Add basic JSON_TABLE() functionality

JSON_TABLE() allows JSON data to be converted into a relational view
and thus used, for example, in a FROM clause, like other tabular
data.  Data to show in the view is selected from a source JSON object
using a JSON path expression to get a sequence of JSON objects that's
called a "row pattern", which becomes the source to compute the
SQL/JSON values that populate the view's output columns.  Column
values themselves are computed using JSON path expressions applied to
each of the JSON objects comprising the "row pattern", for which the
SQL/JSON query functions added in 6185c9737c are used.

To implement JSON_TABLE() as a table function, this augments the
TableFunc and TableFuncScanState nodes that are currently used to
support XMLTABLE() with some JSON_TABLE()-specific fields.

Note that the JSON_TABLE() spec includes NESTED COLUMNS and PLAN
clauses, which are required to provide more flexibility to extract
data out of nested JSON objects, but they are not implemented here
to keep this commit of manageable size.

Author: Nikita Glukhov <n.gluhov@postgrespro.ru>
Author: Teodor Sigaev <teodor@sigaev.ru>
Author: Oleg Bartunov <obartunov@gmail.com>
Author: Alexander Korotkov <aekorotkov@gmail.com>
Author: Andrew Dunstan <andrew@dunslane.net>
Author: Amit Langote <amitlangote09@gmail.com>
Author: Jian He <jian.universality@gmail.com>

Reviewers have included (in no particular order):

Andres Freund, Alexander Korotkov, Pavel Stehule, Andrew Alsup,
Erik Rijkers, Zihong Yu, Himanshu Upadhyaya, Daniel Gustafsson,
Justin Pryzby, Álvaro Herrera, Jian He

Discussion: https://postgr.es/m/cd0bb935-0158-78a7-08b5-904886deac4b@postgrespro.ru
Discussion: https://postgr.es/m/20220616233130.rparivafipt6doj3@alap3.anarazel.de
Discussion: https://postgr.es/m/abd9b83b-aa66-f230-3d6d-734817f0995d%40postgresql.org
Discussion: https://postgr.es/m/CA+HiwqE4XTdfb1nW=Ojoy_tQSRhYt-q_kb6i5d4xcKyrLC1Nbg@mail.gmail.com
This commit is contained in:
Amit Langote 2024-04-04 19:57:08 +09:00
parent a9d6c38684
commit de3600452b
35 changed files with 2943 additions and 52 deletions

View File

@ -18859,6 +18859,340 @@ DETAIL: Missing "]" after array dimensions.
</tgroup>
</table>
</sect2>
<sect2 id="functions-sqljson-table">
<title>JSON_TABLE</title>
<indexterm>
<primary>json_table</primary>
</indexterm>
<para>
<function>JSON_TABLE</function> is an SQL/JSON function which
queries <acronym>JSON</acronym> data
and presents the results as a relational view, which can be accessed as a
regular SQL table. You can use <function>JSON_TABLE</function> inside
the <literal>FROM</literal> clause of a <literal>SELECT</literal>,
<literal>UPDATE</literal>, or <literal>DELETE</literal> and as data source
in a <literal>MERGE</literal> statement.
</para>
<para>
Taking JSON data as input, <function>JSON_TABLE</function> uses a JSON path
expression to extract a part of the provided data to use as a
<firstterm>row pattern</firstterm> for the constructed view. Each SQL/JSON
value given by the row pattern serves as source for a separate row in the
constructed 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, a separate JSON path expression
can be specified to be evaluated against the row pattern to get an SQL/JSON
value that will become the value for the specified column in a given output
row.
</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>
The syntax is:
</para>
<synopsis>
JSON_TABLE (
<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> { <literal>ERROR</literal> | <literal>EMPTY</literal> } <literal>ON ERROR</literal> </optional>
)
<phrase>
where <replaceable class="parameter">json_table_column</replaceable> is:
</phrase>
<replaceable>name</replaceable> FOR ORDINALITY
| <replaceable>name</replaceable> <replaceable>type</replaceable>
<optional> FORMAT JSON <optional>ENCODING <literal>UTF8</literal></optional></optional>
<optional> PATH <replaceable>path_expression</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>path_expression</replaceable> </optional>
<optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </optional>
</synopsis>
<para>
Each syntax element is described below in more detail.
</para>
<variablelist>
<varlistentry>
<term>
<literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> <literal>AS</literal> <replaceable>json_path_name</replaceable> </optional> <optional> <literal>PASSING</literal> { <replaceable>value</replaceable> <literal>AS</literal> <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
</term>
<listitem>
<para>
The input data to query (<replaceable>context_item</replaceable>),
the JSON path expression defining the query (<replaceable>path_expression</replaceable>)
with an optional name (<replaceable>json_path_name</replaceable>), and an
optional <literal>PASSING</literal> clause, which can provide data values
to the <replaceable>path_expression</replaceable>. The result of the input
data evaluation using the aforementioned elements is called the
<firstterm>row pattern</firstterm>, which is used as the source for row
values in the constructed view.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<literal>COLUMNS</literal> ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
</term>
<listitem>
<para>
The <literal>COLUMNS</literal> clause defining the schema of the
constructed view. In this clause, you can specify each column to be
filled with an SQL/JSON value obtained by applying a JSON path expression
against the row pattern. <replaceable>json_table_column</replaceable> has
the following variants:
</para>
<variablelist>
<varlistentry>
<term>
<replaceable>name</replaceable> <literal>FOR ORDINALITY</literal>
</term>
<listitem>
<para>
Adds an ordinality column that provides sequential row numbering starting
from 1.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<literal><replaceable>name</replaceable> <replaceable>type</replaceable>
<optional><literal>FORMAT JSON</literal> <optional>ENCODING <literal>UTF8</literal></optional></optional>
<optional> <literal>PATH</literal> <replaceable>path_expression</replaceable> </optional></literal>
</term>
<listitem>
<para>
Inserts an SQL/JSON value obtained by applying
<replaceable>path_expression</replaceable> against the row pattern into
the view's output row after coercing it to specified
<replaceable>type</replaceable>.
</para>
<para>
Specifying <literal>FORMAT JSON</literal> makes it explicit that you
expect the value to be a valid <type>json</type> object. It only
makes sense to specify <literal>FORMAT JSON</literal> if
<replaceable>type</replaceable> is one of <type>bpchar</type>,
<type>bytea</type>, <type>character varying</type>, <type>name</type>,
<type>json</type>, <type>jsonb</type>, <type>text</type>, or a domain over
these types.
</para>
<para>
Optionally, you can specify <literal>WRAPPER</literal> and
<literal>QUOTES</literal> clauses to format the output. Note that
specifying <literal>OMIT QUOTES</literal> overrides
<literal>FORMAT JSON</literal> if also specified, because unquoted
literals do not constitute valid <type>json</type> values.
</para>
<para>
Optionally, you can use <literal>ON EMPTY</literal> and
<literal>ON ERROR</literal> clauses to specify whether to throw the error
or return the specified value when the result of JSON path evaluation is
empty and when an error occurs during JSON path evaluation or when
coercing the SQL/JSON value to the specified type, respectively. The
default for both is to return a <literal>NULL</literal> value.
</para>
<note>
<para>
This clause is internally turned into and has the same semantics as
<function>JSON_VALUE</function> or <function>JSON_QUERY</function>.
The latter if the specified type is not a scalar type or if either of
<literal>FORMAT JSON</literal>, <literal>WRAPPER</literal>, or
<literal>QUOTES</literal> clause is present.
</para>
</note>
</listitem>
</varlistentry>
<varlistentry>
<term>
<replaceable>name</replaceable> <replaceable>type</replaceable>
<literal>EXISTS</literal> <optional> <literal>PATH</literal> <replaceable>path_expression</replaceable> </optional>
</term>
<listitem>
<para>
Inserts a boolean value obtained by applying
<replaceable>path_expression</replaceable> against the row pattern
into the view's output row after coercing it to specified
<replaceable>type</replaceable>.
</para>
<para>
The value corresponds to whether applying the <literal>PATH</literal>
expression to the row pattern yields any values.
</para>
<para>
The specified <replaceable>type</replaceable> should have a cast from the
<type>boolean</type> type.
</para>
<para>
Optionally, you can use <literal>ON ERROR</literal> to specify whether to
throw the error or return the specified value when an error occurs during
JSON path evaluation or when coercing SQL/JSON value to the specified
type. The default is to return a boolean value
<literal>FALSE</literal>.
</para>
<note>
<para>
This clause is internally turned into and has the same semantics as
<function>JSON_EXISTS</function>.
</para>
</note>
</listitem>
</varlistentry>
</variablelist>
<note>
<para>
In each variant of <replaceable>json_table_column</replaceable> described
above, if the <literal>PATH</literal> clause is omitted, path expression
<literal>$.<replaceable>name</replaceable></literal> is used, where
<replaceable>name</replaceable> is the provided column name.
</para>
</note>
</listitem>
</varlistentry>
<varlistentry>
<term>
<literal>AS</literal> <replaceable>json_path_name</replaceable>
</term>
<listitem>
<para>
The optional <replaceable>json_path_name</replaceable> serves as an
identifier of the provided <replaceable>path_expression</replaceable>.
The name must be unique and distinct from the column names.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
{ <literal>ERROR</literal> | <literal>EMPTY</literal> } <literal>ON ERROR</literal>
</term>
<listitem>
<para>
The optional <literal>ON ERROR</literal> can be used to specify how to
handle errors when evaluating the top-level
<replaceable>path_expression</replaceable>. Use <literal>ERROR</literal>
if you want the errors to be thrown and <literal>EMPTY</literal> to
return an empty table, that is, a table containing 0 rows. Note that
this clause does not affect the errors that occur when evaluating
columns, for which the behavior depends on whether the
<literal>ON ERROR</literal> clause is specified against a given column.
</para>
</listitem>
</varlistentry>
</variablelist>
<para>Examples</para>
<para>
In the examples that follow, the following table containing JSON data
will be used:
<programlisting>
CREATE TABLE my_films ( js jsonb );
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>
<para>
The following query shows how to use <function>JSON_TABLE</function> to
turn the JSON objects in the <structname>my_films</structname> table
to a view containing columns for the keys <literal>kind</literal>,
<literal>title</literal>, and <literal>director</literal> contained in
the original JSON along with an ordinality column:
<programlisting>
SELECT jt.* FROM
my_films,
JSON_TABLE (js, '$.favorites[*]' COLUMNS (
id FOR ORDINALITY,
kind text PATH '$.kind',
title text PATH '$.films[*].title' WITH WRAPPER,
director text PATH '$.films[*].director' WITH WRAPPER)) AS jt;
</programlisting>
<screen>
id | kind | title | director
----+----------+--------------------------------+----------------------------------
1 | comedy | ["Bananas", "The Dinner Game"] | ["Woody Allen", "Francis Veber"]
2 | horror | ["Psycho"] | ["Alfred Hitchcock"]
3 | thriller | ["Vertigo"] | ["Alfred Hitchcock"]
4 | drama | ["Yojimbo"] | ["Akira Kurosawa"]
(4 rows)
</screen>
</para>
<para>
The following is a modified version of the above query to show the
usage of <literal>PASSING</literal> arguments in the filter specified in
the top-level JSON path expression and the various options for the
individual columns:
<programlisting>
SELECT jt.* FROM
my_films,
JSON_TABLE (js, '$.favorites[*] ? (@.films[*].director == $filter)'
PASSING 'Alfred Hitchcock' AS filter, 'Vertigo' AS filter2
COLUMNS (
id FOR ORDINALITY,
kind text PATH '$.kind',
title text FORMAT JSON PATH '$.films[*].title' OMIT QUOTES,
director text PATH '$.films[*].director' KEEP QUOTES)) AS jt;
</programlisting>
<screen>
id | kind | title | director
----+----------+---------+--------------------
1 | horror | Psycho | "Alfred Hitchcock"
2 | thriller | Vertigo | "Alfred Hitchcock"
(2 rows)
</screen>
</para>
</sect2>
</sect1>
<sect1 id="functions-sequence">

View File

@ -4087,9 +4087,24 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
}
break;
case T_TableFuncScan:
Assert(rte->rtekind == RTE_TABLEFUNC);
objectname = "xmltable";
objecttag = "Table Function Name";
{
TableFunc *tablefunc = ((TableFuncScan *) plan)->tablefunc;
Assert(rte->rtekind == RTE_TABLEFUNC);
switch (tablefunc->functype)
{
case TFT_XMLTABLE:
objectname = "xmltable";
break;
case TFT_JSON_TABLE:
objectname = "json_table";
break;
default:
elog(ERROR, "invalid TableFunc type %d",
(int) tablefunc->functype);
}
objecttag = "Table Function Name";
}
break;
case T_ValuesScan:
Assert(rte->rtekind == RTE_VALUES);

View File

@ -2436,7 +2436,16 @@ ExecInitExprRec(Expr *node, ExprState *state,
{
JsonExpr *jsexpr = castNode(JsonExpr, node);
ExecInitJsonExpr(jsexpr, state, resv, resnull, &scratch);
/*
* No need to initialize a full JsonExprState For
* JSON_TABLE(), because the upstream caller tfuncFetchRows()
* is only interested in the value of formatted_expr.
*/
if (jsexpr->op == JSON_TABLE_OP)
ExecInitExprRec((Expr *) jsexpr->formatted_expr, state,
resv, resnull);
else
ExecInitJsonExpr(jsexpr, state, resv, resnull, &scratch);
break;
}

View File

@ -4370,6 +4370,8 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
break;
}
/* JSON_TABLE_OP can't happen here */
default:
elog(ERROR, "unrecognized SQL/JSON expression op %d",
(int) jsexpr->op);

View File

@ -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,
@ -182,6 +184,10 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
ExecInitExprList(tf->colexprs, (PlanState *) scanstate);
scanstate->coldefexprs =
ExecInitExprList(tf->coldefexprs, (PlanState *) scanstate);
scanstate->colvalexprs =
ExecInitExprList(tf->colvalexprs, (PlanState *) scanstate);
scanstate->passingvalexprs =
ExecInitExprList(tf->passingvalexprs, (PlanState *) scanstate);
scanstate->notnulls = tf->notnulls;
@ -274,11 +280,12 @@ tfuncFetchRows(TableFuncScanState *tstate, ExprContext *econtext)
/*
* Each call to fetch a new set of rows - of which there may be very many
* if XMLTABLE is being used in a lateral join - will allocate a possibly
* substantial amount of memory, so we cannot use the per-query context
* here. perTableCxt now serves the same function as "argcontext" does in
* FunctionScan - a place to store per-one-call (i.e. one result table)
* lifetime data (as opposed to per-query or per-result-tuple).
* if XMLTABLE or JSON_TABLE is being used in a lateral join - will
* allocate a possibly substantial amount of memory, so we cannot use the
* per-query context here. perTableCxt now serves the same function as
* "argcontext" does in FunctionScan - a place to store per-one-call (i.e.
* one result table) lifetime data (as opposed to per-query or
* per-result-tuple).
*/
MemoryContextSwitchTo(tstate->perTableCxt);
@ -369,14 +376,20 @@ 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")));
/*
* Install the row filter expression, if any, into the table builder
* context.
*/
if (routine->SetRowFilter)
{
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.

View File

@ -537,6 +537,22 @@ makeFuncExpr(Oid funcid, Oid rettype, List *args,
return funcexpr;
}
/*
* makeStringConst -
* build a A_Const node of type T_String for given string
*/
Node *
makeStringConst(char *str, int location)
{
A_Const *n = makeNode(A_Const);
n->val.sval.type = T_String;
n->val.sval.sval = str;
n->location = location;
return (Node *) n;
}
/*
* makeDefElem -
* build a DefElem node
@ -905,3 +921,40 @@ makeJsonIsPredicate(Node *expr, JsonFormat *format, JsonValueType item_type,
return (Node *) n;
}
/*
* makeJsonTablePathSpec -
* Make JsonTablePathSpec node from given path string and name (if any)
*/
JsonTablePathSpec *
makeJsonTablePathSpec(char *string, char *name, int string_location,
int name_location)
{
JsonTablePathSpec *pathspec = makeNode(JsonTablePathSpec);
Assert(string != NULL);
pathspec->string = makeStringConst(string, string_location);
if (name != NULL)
pathspec->name = pstrdup(name);
pathspec->name_location = name_location;
pathspec->location = string_location;
return pathspec;
}
/*
* makeJsonTablePath -
* Make JsonTablePath node for given path string and name
*/
JsonTablePath *
makeJsonTablePath(Const *pathvalue, char *pathname)
{
JsonTablePath *path = makeNode(JsonTablePath);
Assert(IsA(pathvalue, Const));
path->value = pathvalue;
path->name = pathname;
return path;
}

View File

@ -2650,6 +2650,10 @@ expression_tree_walker_impl(Node *node,
return true;
if (WALK(tf->coldefexprs))
return true;
if (WALK(tf->colvalexprs))
return true;
if (WALK(tf->passingvalexprs))
return true;
}
break;
default:
@ -3702,6 +3706,8 @@ expression_tree_mutator_impl(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 *);
MUTATE(newnode->passingvalexprs, tf->passingvalexprs, List *);
return (Node *) newnode;
}
break;
@ -4127,6 +4133,36 @@ raw_expression_tree_walker_impl(Node *node,
return true;
}
break;
case T_JsonTable:
{
JsonTable *jt = (JsonTable *) node;
if (WALK(jt->context_item))
return true;
if (WALK(jt->pathspec))
return true;
if (WALK(jt->passing))
return true;
if (WALK(jt->columns))
return true;
if (WALK(jt->on_error))
return true;
}
break;
case T_JsonTableColumn:
{
JsonTableColumn *jtc = (JsonTableColumn *) node;
if (WALK(jtc->typeName))
return true;
if (WALK(jtc->on_empty))
return true;
if (WALK(jtc->on_error))
return true;
}
break;
case T_JsonTablePathSpec:
return WALK(((JsonTablePathSpec *) node)->string);
case T_NullTest:
return WALK(((NullTest *) node)->arg);
case T_BooleanTest:

View File

@ -23,6 +23,7 @@ OBJS = \
parse_enr.o \
parse_expr.o \
parse_func.o \
parse_jsontable.o \
parse_merge.o \
parse_node.o \
parse_oper.o \

View File

@ -170,7 +170,6 @@ static void updateRawStmtEnd(RawStmt *rs, int end_location);
static Node *makeColumnRef(char *colname, List *indirection,
int location, core_yyscan_t yyscanner);
static Node *makeTypeCast(Node *arg, TypeName *typename, int location);
static Node *makeStringConst(char *str, int location);
static Node *makeStringConstCast(char *str, int location, TypeName *typename);
static Node *makeIntConst(int val, int location);
static Node *makeFloatConst(char *str, int location);
@ -659,12 +658,17 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
json_argument
json_behavior
json_on_error_clause_opt
json_table
json_table_column_definition
json_table_column_path_clause_opt
%type <list> json_name_and_value_list
json_value_expr_list
json_array_aggregate_order_by_clause_opt
json_arguments
json_behavior_clause_opt
json_passing_clause_opt
json_table_column_definition_list
%type <str> json_table_path_name_opt
%type <ival> json_behavior_type
json_predicate_type_constraint
json_quotes_clause_opt
@ -737,7 +741,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
KEEP KEY KEYS
@ -748,8 +752,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
MAPPING MATCH MATCHED MATERIALIZED MAXVALUE MERGE MERGE_ACTION 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 NEW NEXT NFC NFD NFKC NFKD NO
NONE NORMALIZE NORMALIZED
NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
NULLS_P NUMERIC
@ -757,8 +761,9 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
ORDER ORDINALITY OTHERS OUT_P OUTER_P
OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
PARALLEL PARAMETER PARSER PARTIAL PARTITION PASSING PASSWORD
PERIOD PLACING PLANS POLICY
PARALLEL PARAMETER PARSER PARTIAL PARTITION PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@ -877,9 +882,9 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
* json_predicate_type_constraint and json_key_uniqueness_constraint_opt
* productions (see comments there).
*/
%nonassoc UNBOUNDED /* ideally would have same precedence as IDENT */
%nonassoc UNBOUNDED /* ideally would have same precedence as IDENT */
%nonassoc IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
SET KEYS OBJECT_P SCALAR VALUE_P WITH WITHOUT
SET KEYS OBJECT_P SCALAR VALUE_P WITH WITHOUT PATH
%left Op OPERATOR /* multi-character ops and user-defined operators */
%left '+' '-'
%left '*' '/' '%'
@ -13493,6 +13498,21 @@ 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;
}
;
@ -14060,6 +14080,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:
@ -14088,6 +14110,123 @@ xml_namespace_el:
}
;
json_table:
JSON_TABLE '('
json_value_expr ',' a_expr json_table_path_name_opt
json_passing_clause_opt
COLUMNS '(' json_table_column_definition_list ')'
json_on_error_clause_opt
')'
{
JsonTable *n = makeNode(JsonTable);
char *pathstring;
n->context_item = (JsonValueExpr *) $3;
if (!IsA($5, A_Const) ||
castNode(A_Const, $5)->val.node.type != T_String)
ereport(ERROR,
errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("only string constants are supported in JSON_TABLE path specification"),
parser_errposition(@5));
pathstring = castNode(A_Const, $5)->val.sval.sval;
n->pathspec = makeJsonTablePathSpec(pathstring, $6, @5, @6);
n->passing = $7;
n->columns = $10;
n->on_error = (JsonBehavior *) $12;
n->location = @1;
$$ = (Node *) n;
}
;
json_table_path_name_opt:
AS name { $$ = $2; }
| /* empty */ { $$ = NULL; }
;
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:
ColId FOR ORDINALITY
{
JsonTableColumn *n = makeNode(JsonTableColumn);
n->coltype = JTC_FOR_ORDINALITY;
n->name = $1;
n->location = @1;
$$ = (Node *) n;
}
| ColId Typename
json_table_column_path_clause_opt
json_wrapper_behavior
json_quotes_clause_opt
json_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->pathspec = (JsonTablePathSpec *) $3;
n->wrapper = $4;
n->quotes = $5;
n->on_empty = (JsonBehavior *) linitial($6);
n->on_error = (JsonBehavior *) lsecond($6);
n->location = @1;
$$ = (Node *) n;
}
| ColId Typename json_format_clause
json_table_column_path_clause_opt
json_wrapper_behavior
json_quotes_clause_opt
json_behavior_clause_opt
{
JsonTableColumn *n = makeNode(JsonTableColumn);
n->coltype = JTC_FORMATTED;
n->name = $1;
n->typeName = $2;
n->format = (JsonFormat *) $3;
n->pathspec = (JsonTablePathSpec *) $4;
n->wrapper = $5;
n->quotes = $6;
n->on_empty = (JsonBehavior *) linitial($7);
n->on_error = (JsonBehavior *) lsecond($7);
n->location = @1;
$$ = (Node *) n;
}
| ColId Typename
EXISTS json_table_column_path_clause_opt
json_behavior_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->quotes = JS_QUOTES_UNSPEC;
n->pathspec = (JsonTablePathSpec *) $4;
n->on_empty = (JsonBehavior *) linitial($5);
n->on_error = (JsonBehavior *) lsecond($5);
n->location = @1;
$$ = (Node *) n;
}
;
json_table_column_path_clause_opt:
PATH Sconst
{ $$ = (Node *) makeJsonTablePathSpec($2, NULL, @2, -1); }
| /* EMPTY */
{ $$ = NULL; }
;
/*****************************************************************************
*
* Type syntax
@ -17531,7 +17670,9 @@ unreserved_keyword:
| PARTITION
| PASSING
| PASSWORD
| PATH
| PERIOD
| PLAN
| PLANS
| POLICY
| PRECEDING
@ -17698,6 +17839,7 @@ col_name_keyword:
| JSON_QUERY
| JSON_SCALAR
| JSON_SERIALIZE
| JSON_TABLE
| JSON_VALUE
| LEAST
| MERGE_ACTION
@ -18067,6 +18209,7 @@ bare_label_keyword:
| JSON_QUERY
| JSON_SCALAR
| JSON_SERIALIZE
| JSON_TABLE
| JSON_VALUE
| KEEP
| KEY
@ -18151,8 +18294,10 @@ bare_label_keyword:
| PARTITION
| PASSING
| PASSWORD
| PATH
| PERIOD
| PLACING
| PLAN
| PLANS
| POLICY
| POSITION
@ -18422,18 +18567,6 @@ makeTypeCast(Node *arg, TypeName *typename, int location)
return (Node *) n;
}
static Node *
makeStringConst(char *str, int location)
{
A_Const *n = makeNode(A_Const);
n->val.sval.type = T_String;
n->val.sval.sval = str;
n->location = location;
return (Node *) n;
}
static Node *
makeStringConstCast(char *str, int location, TypeName *typename)
{

View File

@ -10,6 +10,7 @@ backend_sources += files(
'parse_enr.c',
'parse_expr.c',
'parse_func.c',
'parse_jsontable.c',
'parse_merge.c',
'parse_node.c',
'parse_oper.c',

View File

@ -695,7 +695,11 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
char **names;
int colno;
/* Currently only XMLTABLE is supported */
/*
* Currently we only support XMLTABLE here. See transformJsonTable() for
* JSON_TABLE support.
*/
tf->functype = TFT_XMLTABLE;
constructName = "XMLTABLE";
docType = XMLOID;
@ -1102,13 +1106,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, JsonTable))
nsitem = transformJsonTable(pstate, (JsonTable *) n);
else
nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
*top_nsitem = nsitem;
*namespace = list_make1(nsitem);
rtr = makeNode(RangeTblRef);

View File

@ -4245,7 +4245,8 @@ transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr)
}
/*
* Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS functions into a JsonExpr node.
* Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS, JSON_TABLE functions into
* a JsonExpr node.
*/
static Node *
transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
@ -4269,6 +4270,9 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
func_name = "JSON_VALUE";
default_format = JS_FORMAT_DEFAULT;
break;
case JSON_TABLE_OP:
func_name = "JSON_TABLE";
break;
default:
elog(ERROR, "invalid JsonFuncExpr op %d", (int) func->op);
break;
@ -4350,6 +4354,42 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
jsexpr->returning->typmod = -1;
}
/* JSON_TABLE() COLUMNS can specify a non-boolean type. */
if (jsexpr->returning->typid != BOOLOID)
{
Node *coercion_expr;
CaseTestExpr *placeholder = makeNode(CaseTestExpr);
int location = exprLocation((Node *) jsexpr);
/*
* We abuse CaseTestExpr here as placeholder to pass the
* result of evaluating JSON_EXISTS to the coercion
* expression.
*/
placeholder->typeId = BOOLOID;
placeholder->typeMod = -1;
placeholder->collation = InvalidOid;
coercion_expr =
coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
jsexpr->returning->typid,
jsexpr->returning->typmod,
COERCION_EXPLICIT,
COERCE_IMPLICIT_CAST,
location);
if (coercion_expr == NULL)
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 (coercion_expr != (Node *) placeholder)
jsexpr->coercion_expr = coercion_expr;
}
jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
JSON_BEHAVIOR_FALSE,
jsexpr->returning);
@ -4414,6 +4454,17 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
jsexpr->returning);
break;
case JSON_TABLE_OP:
if (!OidIsValid(jsexpr->returning->typid))
{
jsexpr->returning->typid = exprType(jsexpr->formatted_expr);
jsexpr->returning->typmod = -1;
}
jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
JSON_BEHAVIOR_EMPTY,
jsexpr->returning);
break;
default:
elog(ERROR, "invalid JsonFuncExpr op %d", (int) func->op);
break;

View File

@ -0,0 +1,421 @@
/*-------------------------------------------------------------------------
*
* parse_jsontable.c
* parsing of JSON_TABLE
*
* Portions Copyright (c) 1996-2024, 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 transformJsonTableColumns() */
typedef struct JsonTableParseContext
{
ParseState *pstate;
JsonTable *jt;
TableFunc *tf;
List *pathNames; /* list of all path and columns names */
int pathNameId; /* path name id counter */
} JsonTableParseContext;
static JsonTablePlan *transformJsonTableColumns(JsonTableParseContext *cxt,
List *columns,
List *passingArgs,
JsonTablePathSpec *pathspec);
static JsonFuncExpr *transformJsonTableColumn(JsonTableColumn *jtc,
Node *contextItemExpr,
List *passingArgs);
static bool isCompositeType(Oid typid);
static JsonTablePlan *makeJsonTablePathScan(JsonTablePathSpec *pathspec,
bool errorOnError);
static void CheckDuplicateColumnOrPathNames(JsonTableParseContext *cxt,
List *columns);
static bool LookupPathOrColumnName(JsonTableParseContext *cxt, char *name);
static char *generateJsonTablePathName(JsonTableParseContext *cxt);
/*
* transformJsonTable -
* Transform a raw JsonTable into TableFunc
*
* Mainly, this transforms the JSON_TABLE() document-generating expression
* (jt->context_item) and the column-generating expressions (jt->columns) to
* populate TableFunc.docexpr and TableFunc.colvalexprs, respectively. Also,
* the PASSING values (jt->passing) are transformed and added into
* TableFunc.passvalexprs.
*/
ParseNamespaceItem *
transformJsonTable(ParseState *pstate, JsonTable *jt)
{
TableFunc *tf;
JsonFuncExpr *jfe;
JsonExpr *je;
JsonTablePathSpec *rootPathSpec = jt->pathspec;
bool is_lateral;
JsonTableParseContext cxt = {pstate};
Assert(IsA(rootPathSpec->string, A_Const) &&
castNode(A_Const, rootPathSpec->string)->val.node.type == T_String);
if (jt->on_error &&
jt->on_error->btype != JSON_BEHAVIOR_ERROR &&
jt->on_error->btype != JSON_BEHAVIOR_EMPTY &&
jt->on_error->btype != JSON_BEHAVIOR_EMPTY_ARRAY)
ereport(ERROR,
errcode(ERRCODE_SYNTAX_ERROR),
errmsg("invalid ON ERROR behavior"),
errdetail("Only EMPTY or ERROR is allowed in the top-level ON ERROR clause."),
parser_errposition(pstate, jt->on_error->location));
cxt.pathNameId = 0;
if (rootPathSpec->name == NULL)
rootPathSpec->name = generateJsonTablePathName(&cxt);
cxt.pathNames = list_make1(rootPathSpec->name);
CheckDuplicateColumnOrPathNames(&cxt, jt->columns);
/*
* 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 = makeNode(TableFunc);
tf->functype = TFT_JSON_TABLE;
/*
* Transform JsonFuncExpr representing the top JSON_TABLE context_item and
* pathspec into a dummy JSON_TABLE_OP JsonExpr.
*/
jfe = makeNode(JsonFuncExpr);
jfe->op = JSON_TABLE_OP;
jfe->context_item = jt->context_item;
jfe->pathspec = (Node *) rootPathSpec->string;
jfe->passing = jt->passing;
jfe->on_empty = NULL;
jfe->on_error = jt->on_error;
jfe->location = jt->location;
tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
/*
* Create a JsonTablePlan that will generate row pattern that becomes
* source data for JSON path expressions in jt->columns. This also adds
* the columns' transformed JsonExpr nodes into tf->colvalexprs.
*/
cxt.jt = jt;
cxt.tf = tf;
tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns,
jt->passing,
rootPathSpec);
/*
* Copy the transformed PASSING arguments into the TableFunc node, because
* they are evaluated separately from the JsonExpr that we just put in
* TableFunc.docexpr. JsonExpr.passing_values is still kept around for
* get_json_table().
*/
je = (JsonExpr *) tf->docexpr;
tf->passingvalexprs = copyObject(je->passing_values);
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);
}
/*
* Check if a column / path name is duplicated in the given shared list of
* names.
*/
static void
CheckDuplicateColumnOrPathNames(JsonTableParseContext *cxt,
List *columns)
{
ListCell *lc1;
foreach(lc1, columns)
{
JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
if (LookupPathOrColumnName(cxt, jtc->name))
ereport(ERROR,
errcode(ERRCODE_DUPLICATE_ALIAS),
errmsg("duplicate JSON_TABLE column or path name: %s",
jtc->name),
parser_errposition(cxt->pstate, jtc->location));
cxt->pathNames = lappend(cxt->pathNames, jtc->name);
}
}
/*
* Lookup a column/path name in the given name list, returning true if already
* there.
*/
static bool
LookupPathOrColumnName(JsonTableParseContext *cxt, char *name)
{
ListCell *lc;
foreach(lc, cxt->pathNames)
{
if (strcmp(name, (const char *) lfirst(lc)) == 0)
return true;
}
return false;
}
/* Generate a new unique JSON_TABLE path name. */
static char *
generateJsonTablePathName(JsonTableParseContext *cxt)
{
char namebuf[32];
char *name = namebuf;
snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
cxt->pathNameId++);
name = pstrdup(name);
cxt->pathNames = lappend(cxt->pathNames, name);
return name;
}
/*
* Create a JsonTablePlan that will supply the source row for 'columns'
* using 'pathspec' and append the columns' transformed JsonExpr nodes and
* their type/collation information to cxt->tf.
*/
static JsonTablePlan *
transformJsonTableColumns(JsonTableParseContext *cxt, List *columns,
List *passingArgs,
JsonTablePathSpec *pathspec)
{
ParseState *pstate = cxt->pstate;
JsonTable *jt = cxt->jt;
TableFunc *tf = cxt->tf;
ListCell *col;
bool ordinality_found = false;
bool errorOnError = jt->on_error &&
jt->on_error->btype == JSON_BEHAVIOR_ERROR;
Oid contextItemTypid = exprType(tf->docexpr);
foreach(col, columns)
{
JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
Oid typid;
int32 typmod;
Oid typcoll = InvalidOid;
Node *colexpr;
Assert(rawc->name);
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:
if (ordinality_found)
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("cannot use more than one FOR ORDINALITY column"),
parser_errposition(pstate, rawc->location)));
ordinality_found = true;
colexpr = NULL;
typid = INT4OID;
typmod = -1;
break;
case JTC_REGULAR:
typenameTypeIdAndMod(pstate, rawc->typeName, &typid, &typmod);
/*
* Use JTC_FORMATTED so as to use JSON_QUERY for this column
* if the specified type is one that's better handled using
* JSON_QUERY() or if non-default WRAPPER or QUOTES behavior
* is specified.
*/
if (isCompositeType(typid) ||
rawc->quotes != JS_QUOTES_UNSPEC ||
rawc->wrapper != JSW_UNSPEC)
rawc->coltype = JTC_FORMATTED;
/* FALLTHROUGH */
case JTC_FORMATTED:
case JTC_EXISTS:
{
JsonFuncExpr *jfe;
CaseTestExpr *param = makeNode(CaseTestExpr);
param->collation = InvalidOid;
param->typeId = contextItemTypid;
param->typeMod = -1;
jfe = transformJsonTableColumn(rawc, (Node *) param,
passingArgs);
colexpr = transformExpr(pstate, (Node *) jfe,
EXPR_KIND_FROM_FUNCTION);
assign_expr_collations(pstate, colexpr);
typid = exprType(colexpr);
typmod = exprTypmod(colexpr);
typcoll = exprCollation(colexpr);
break;
}
default:
elog(ERROR, "unknown JSON_TABLE column type: %d", (int) rawc->coltype);
break;
}
tf->coltypes = lappend_oid(tf->coltypes, typid);
tf->coltypmods = lappend_int(tf->coltypmods, typmod);
tf->colcollations = lappend_oid(tf->colcollations, typcoll);
tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
}
return makeJsonTablePathScan(pathspec, errorOnError);
}
/*
* Check if the type is "composite" for the purpose of checking whether to use
* JSON_VALUE() or JSON_QUERY() for a given JsonTableColumn.
*/
static bool
isCompositeType(Oid typid)
{
char typtype = get_typtype(typid);
return typid == JSONOID ||
typid == JSONBOID ||
typid == RECORDOID ||
type_is_array(typid) ||
typtype == TYPTYPE_COMPOSITE ||
/* domain over one of the above? */
(typtype == TYPTYPE_DOMAIN &&
isCompositeType(getBaseType(typid)));
}
/*
* Transform JSON_TABLE column definition into a JsonFuncExpr
* This turns:
* - regular column into JSON_VALUE()
* - FORMAT JSON column into JSON_QUERY()
* - EXISTS column into JSON_EXISTS()
*/
static JsonFuncExpr *
transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
List *passingArgs)
{
Node *pathspec;
JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
/*
* XXX consider inventing JSON_TABLE_VALUE_OP, etc. and pass the column
* name via JsonExpr so that JsonPathValue(), etc. can provide error
* message tailored to JSON_TABLE(), such as by mentioning the column
* names in the message.
*/
if (jtc->coltype == JTC_REGULAR)
jfexpr->op = JSON_VALUE_OP;
else if (jtc->coltype == JTC_EXISTS)
jfexpr->op = JSON_EXISTS_OP;
else
jfexpr->op = JSON_QUERY_OP;
jfexpr->context_item = makeJsonValueExpr((Expr *) contextItemExpr, NULL,
makeJsonFormat(JS_FORMAT_DEFAULT,
JS_ENC_DEFAULT,
-1));
if (jtc->pathspec)
pathspec = (Node *) jtc->pathspec->string;
else
{
/* Construct default path as '$."column_name"' */
StringInfoData path;
initStringInfo(&path);
appendStringInfoString(&path, "$.");
escape_json(&path, jtc->name);
pathspec = makeStringConst(path.data, -1);
}
jfexpr->pathspec = pathspec;
jfexpr->passing = passingArgs;
jfexpr->output = makeNode(JsonOutput);
jfexpr->output->typeName = jtc->typeName;
jfexpr->output->returning = makeNode(JsonReturning);
jfexpr->output->returning->format = jtc->format;
jfexpr->on_empty = jtc->on_empty;
jfexpr->on_error = jtc->on_error;
jfexpr->quotes = jtc->quotes;
jfexpr->wrapper = jtc->wrapper;
jfexpr->location = jtc->location;
return jfexpr;
}
/*
* Create a JsonTablePlan for given path and ON ERROR behavior.
*/
static JsonTablePlan *
makeJsonTablePathScan(JsonTablePathSpec *pathspec, bool errorOnError)
{
JsonTablePathScan *scan = makeNode(JsonTablePathScan);
char *pathstring;
Const *value;
Assert(IsA(pathspec->string, A_Const));
pathstring = castNode(A_Const, pathspec->string)->val.sval.sval;
value = makeConst(JSONPATHOID, -1, InvalidOid, -1,
DirectFunctionCall1(jsonpath_in,
CStringGetDatum(pathstring)),
false, false);
scan->plan.type = T_JsonTablePathScan;
scan->path = makeJsonTablePath(value, pathspec->name);
scan->errorOnError = errorOnError;
return (JsonTablePlan *) scan;
}

View File

@ -2071,8 +2071,6 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
Assert(list_length(tf->coltypmods) == list_length(tf->colnames));
Assert(list_length(tf->colcollations) == list_length(tf->colnames));
refname = alias ? alias->aliasname : pstrdup("xmltable");
rte->rtekind = RTE_TABLEFUNC;
rte->relid = InvalidOid;
rte->subquery = NULL;
@ -2082,6 +2080,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
rte->colcollations = tf->colcollations;
rte->alias = alias;
refname = alias ? alias->aliasname :
pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
eref = alias ? copyObject(alias) : makeAlias(refname, NIL);
numaliases = list_length(eref->colnames);
@ -2094,7 +2094,7 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
ereport(ERROR,
(errcode(ERRCODE_INVALID_COLUMN_REFERENCE),
errmsg("%s function has %d columns available but %d columns specified",
"XMLTABLE",
tf->functype == TFT_XMLTABLE ? "XMLTABLE" : "JSON_TABLE",
list_length(tf->colnames), numaliases)));
rte->eref = eref;

View File

@ -2019,6 +2019,7 @@ FigureColnameInternal(Node *node, char **name)
case JSON_VALUE_OP:
*name = "json_value";
return 2;
/* JSON_TABLE_OP can't happen here. */
default:
elog(ERROR, "unrecognized JsonExpr op: %d",
(int) ((JsonFuncExpr *) node)->op);

View File

@ -61,9 +61,11 @@
#include "catalog/pg_collation.h"
#include "catalog/pg_type.h"
#include "executor/execExpr.h"
#include "funcapi.h"
#include "miscadmin.h"
#include "nodes/miscnodes.h"
#include "nodes/nodeFuncs.h"
#include "regex/regex.h"
#include "utils/builtins.h"
#include "utils/date.h"
@ -71,6 +73,8 @@
#include "utils/float.h"
#include "utils/formatting.h"
#include "utils/jsonpath.h"
#include "utils/lsyscache.h"
#include "utils/memutils.h"
#include "utils/timestamp.h"
/*
@ -154,6 +158,63 @@ typedef struct JsonValueListIterator
ListCell *next;
} JsonValueListIterator;
/* Structures for JSON_TABLE execution */
/*
* Struct holding the result of jsonpath evaluation, to be used as source row
* for JsonTableGetValue() which in turn computes the values of individual
* JSON_TABLE columns.
*/
typedef struct JsonTablePlanRowSource
{
Datum value;
bool isnull;
} JsonTablePlanRowSource;
/*
* State of evaluation of row pattern derived by applying jsonpath given in
* a JsonTablePlan to an input document given in the parent TableFunc.
*/
typedef struct JsonTablePlanState
{
/* Original plan */
JsonTablePlan *plan;
/* The following fields are only valid for JsonTablePathScan plans */
/* jsonpath to evaluate against the input doc to get the row pattern */
JsonPath *path;
/*
* Memory context to use when evaluating the row pattern from the jsonpath
*/
MemoryContext mcxt;
/* PASSING arguments passed to jsonpath executor */
List *args;
/* List and iterator of jsonpath result values */
JsonValueList found;
JsonValueListIterator iter;
/* Currently selected row for JsonTableGetValue() to use */
JsonTablePlanRowSource current;
/* Counter for ORDINAL columns */
int ordinal;
} JsonTablePlanState;
/* Random number to identify JsonTableExecContext for sanity checking */
#define JSON_TABLE_EXEC_CONTEXT_MAGIC 418352867
typedef struct JsonTableExecContext
{
int magic;
/* State of the plan providing a row evaluated from "root" jsonpath */
JsonTablePlanState *rootplanstate;
} JsonTableExecContext;
/* strict/lax flags is decomposed into four [un]wrap/error flags */
#define jspStrictAbsenceOfErrors(cxt) (!(cxt)->laxMode)
#define jspAutoUnwrap(cxt) ((cxt)->laxMode)
@ -253,6 +314,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);
@ -272,6 +334,31 @@ static int compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
static void checkTimezoneIsUsedForCast(bool useTz, const char *type1,
const char *type2);
static void JsonTableInitOpaque(TableFuncScanState *state, int natts);
static JsonTablePlanState *JsonTableInitPlan(JsonTableExecContext *cxt,
JsonTablePlan *plan,
List *args,
MemoryContext mcxt);
static void JsonTableSetDocument(TableFuncScanState *state, Datum value);
static void JsonTableResetRowPattern(JsonTablePlanState *plan, Datum item);
static bool JsonTableFetchRow(TableFuncScanState *state);
static Datum JsonTableGetValue(TableFuncScanState *state, int colnum,
Oid typid, int32 typmod, bool *isnull);
static void JsonTableDestroyOpaque(TableFuncScanState *state);
static bool JsonTablePlanNextRow(JsonTablePlanState *planstate);
const TableFuncRoutine JsonbTableRoutine =
{
.InitOpaque = JsonTableInitOpaque,
.SetDocument = JsonTableSetDocument,
.SetNamespace = NULL,
.SetRowFilter = NULL,
.SetColumnFilter = NULL,
.FetchRow = JsonTableFetchRow,
.GetValue = JsonTableGetValue,
.DestroyOpaque = JsonTableDestroyOpaque
};
/****************** User interface to JsonPath executor ********************/
/*
@ -3383,6 +3470,13 @@ setBaseObject(JsonPathExecContext *cxt, JsonbValue *jbv, int32 id)
return baseObject;
}
static void
JsonValueListClear(JsonValueList *jvl)
{
jvl->singleton = NULL;
jvl->list = NIL;
}
static void
JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
{
@ -3918,3 +4012,281 @@ JsonPathValue(Datum jb, JsonPath *jp, bool *empty, bool *error, List *vars)
return res;
}
/************************ JSON_TABLE functions ***************************/
/*
* Sanity-checks and returns the opaque JsonTableExecContext from the
* given executor state struct.
*/
static inline JsonTableExecContext *
GetJsonTableExecContext(TableFuncScanState *state, const char *fname)
{
JsonTableExecContext *result;
if (!IsA(state, TableFuncScanState))
elog(ERROR, "%s called with invalid TableFuncScanState", fname);
result = (JsonTableExecContext *) state->opaque;
if (result->magic != JSON_TABLE_EXEC_CONTEXT_MAGIC)
elog(ERROR, "%s called with invalid TableFuncScanState", fname);
return result;
}
/*
* JsonTableInitOpaque
* Fill in TableFuncScanState->opaque for processing JSON_TABLE
*
* This initializes the PASSING arguments and the JsonTablePlanState for
* JsonTablePlan given in TableFunc.
*/
static void
JsonTableInitOpaque(TableFuncScanState *state, int natts)
{
JsonTableExecContext *cxt;
PlanState *ps = &state->ss.ps;
TableFuncScan *tfs = castNode(TableFuncScan, ps->plan);
TableFunc *tf = tfs->tablefunc;
JsonTablePlan *rootplan = (JsonTablePlan *) tf->plan;
JsonExpr *je = castNode(JsonExpr, tf->docexpr);
List *args = NIL;
cxt = palloc0(sizeof(JsonTableExecContext));
cxt->magic = JSON_TABLE_EXEC_CONTEXT_MAGIC;
/*
* Evaluate JSON_TABLE() PASSING arguments to be passed to the jsonpath
* executor via JsonPathVariables.
*/
if (state->passingvalexprs)
{
ListCell *exprlc;
ListCell *namelc;
Assert(list_length(state->passingvalexprs) ==
list_length(je->passing_names));
forboth(exprlc, state->passingvalexprs,
namelc, je->passing_names)
{
ExprState *state = lfirst_node(ExprState, exprlc);
String *name = lfirst_node(String, namelc);
JsonPathVariable *var = palloc(sizeof(*var));
var->name = pstrdup(name->sval);
var->typid = exprType((Node *) state->expr);
var->typmod = exprTypmod((Node *) state->expr);
/*
* Evaluate the expression and save the value to be returned by
* GetJsonPathVar().
*/
var->value = ExecEvalExpr(state, ps->ps_ExprContext,
&var->isnull);
args = lappend(args, var);
}
}
/* Initialize plan */
cxt->rootplanstate = JsonTableInitPlan(cxt, rootplan, args,
CurrentMemoryContext);
state->opaque = cxt;
}
/*
* JsonTableDestroyOpaque
* Resets state->opaque
*/
static void
JsonTableDestroyOpaque(TableFuncScanState *state)
{
JsonTableExecContext *cxt =
GetJsonTableExecContext(state, "JsonTableDestroyOpaque");
/* not valid anymore */
cxt->magic = 0;
state->opaque = NULL;
}
/*
* JsonTableInitPlan
* Initialize information for evaluating jsonpath in the given
* JsonTablePlan
*/
static JsonTablePlanState *
JsonTableInitPlan(JsonTableExecContext *cxt, JsonTablePlan *plan,
List *args, MemoryContext mcxt)
{
JsonTablePlanState *planstate = palloc0(sizeof(*planstate));
planstate->plan = plan;
if (IsA(plan, JsonTablePathScan))
{
JsonTablePathScan *scan = (JsonTablePathScan *) plan;
planstate->path = DatumGetJsonPathP(scan->path->value->constvalue);
planstate->args = args;
planstate->mcxt = AllocSetContextCreate(mcxt, "JsonTableExecContext",
ALLOCSET_DEFAULT_SIZES);
/* No row pattern evaluated yet. */
planstate->current.value = PointerGetDatum(NULL);
planstate->current.isnull = true;
}
return planstate;
}
/*
* JsonTableSetDocument
* Install the input document and evaluate the row pattern
*/
static void
JsonTableSetDocument(TableFuncScanState *state, Datum value)
{
JsonTableExecContext *cxt =
GetJsonTableExecContext(state, "JsonTableSetDocument");
JsonTableResetRowPattern(cxt->rootplanstate, value);
}
/*
* Evaluate a JsonTablePlan's jsonpath to get a new row pattren from
* the given context item
*/
static void
JsonTableResetRowPattern(JsonTablePlanState *planstate, Datum item)
{
JsonTablePathScan *scan = castNode(JsonTablePathScan, planstate->plan);
MemoryContext oldcxt;
JsonPathExecResult res;
Jsonb *js = (Jsonb *) DatumGetJsonbP(item);
JsonValueListClear(&planstate->found);
MemoryContextResetOnly(planstate->mcxt);
oldcxt = MemoryContextSwitchTo(planstate->mcxt);
res = executeJsonPath(planstate->path, planstate->args,
GetJsonPathVar, CountJsonPathVars,
js, scan->errorOnError,
&planstate->found,
true);
MemoryContextSwitchTo(oldcxt);
if (jperIsError(res))
{
Assert(!scan->errorOnError);
JsonValueListClear(&planstate->found);
}
/* Reset plan iterator to the beginning of the item list */
JsonValueListInitIterator(&planstate->found, &planstate->iter);
planstate->current.value = PointerGetDatum(NULL);
planstate->current.isnull = true;
planstate->ordinal = 0;
}
/*
* Fetch next row from a JsonTablePlan's path evaluation result.
*
* Returns false if the plan has run out of rows, true otherwise.
*/
static bool
JsonTablePlanNextRow(JsonTablePlanState *planstate)
{
JsonbValue *jbv = JsonValueListNext(&planstate->found, &planstate->iter);
MemoryContext oldcxt;
/* End of list? */
if (jbv == NULL)
{
planstate->current.value = PointerGetDatum(NULL);
planstate->current.isnull = true;
return false;
}
/*
* Set current row item for subsequent JsonTableGetValue() calls for
* evaluating individual columns.
*/
oldcxt = MemoryContextSwitchTo(planstate->mcxt);
planstate->current.value = JsonbPGetDatum(JsonbValueToJsonb(jbv));
planstate->current.isnull = false;
MemoryContextSwitchTo(oldcxt);
/* Next row! */
planstate->ordinal++;
return true;
}
/*
* JsonTableFetchRow
* Prepare the next "current" row for upcoming GetValue calls.
*
* Returns false if no more rows can be returned.
*/
static bool
JsonTableFetchRow(TableFuncScanState *state)
{
JsonTableExecContext *cxt =
GetJsonTableExecContext(state, "JsonTableFetchRow");
return JsonTablePlanNextRow(cxt->rootplanstate);
}
/*
* 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)
{
JsonTableExecContext *cxt =
GetJsonTableExecContext(state, "JsonTableGetValue");
ExprContext *econtext = state->ss.ps.ps_ExprContext;
ExprState *estate = list_nth(state->colvalexprs, colnum);
JsonTablePlanState *planstate = cxt->rootplanstate;
JsonTablePlanRowSource *current = &planstate->current;
Datum result;
/* Row pattern value is NULL */
if (current->isnull)
{
result = (Datum) 0;
*isnull = true;
}
/* Evaluate JsonExpr. */
else if (estate)
{
Datum saved_caseValue = econtext->caseValue_datum;
bool saved_caseIsNull = econtext->caseValue_isNull;
/* Pass the row pattern value via CaseTestExpr. */
econtext->caseValue_datum = current->value;
econtext->caseValue_isNull = false;
result = ExecEvalExpr(estate, econtext, isnull);
econtext->caseValue_datum = saved_caseValue;
econtext->caseValue_isNull = saved_caseIsNull;
}
/* ORDINAL column */
else
{
result = Int32GetDatum(planstate->ordinal);
*isnull = false;
}
return result;
}

View File

@ -524,6 +524,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, deparse_context *context,
bool showimplicit);
#define only_marker(rte) ((rte)->inh ? "" : "ONLY ")
@ -8833,7 +8835,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,
@ -11519,16 +11522,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)
@ -11619,6 +11620,180 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
appendStringInfoChar(buf, ')');
}
/*
* get_json_table_columns - Parse back JSON_TABLE columns
*/
static void
get_json_table_columns(TableFunc *tf, 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_colvalexpr;
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_colvalexpr, 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_colvalexpr));
if (colnum > 0)
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 == JSON_EXISTS_OP)
{
appendStringInfoString(buf, " EXISTS");
default_behavior = JSON_BEHAVIOR_FALSE;
}
else
{
if (colexpr->op == JSON_QUERY_OP)
{
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 (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);
JsonTablePathScan *root = castNode(JsonTablePathScan, 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->value, context, -1);
appendStringInfo(buf, " AS %s", quote_identifier(root->path->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((lfirst_node(String, lc1))->sval)
);
}
if (PRETTY_INDENT(context))
context->indentLevel -= PRETTYINDENT_VAR;
}
get_json_table_columns(tf, 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
*

View File

@ -1963,6 +1963,8 @@ typedef struct TableFuncScanState
ExprState *rowexpr; /* state for row-generating expression */
List *colexprs; /* state for column-generating expression */
List *coldefexprs; /* state for column default expressions */
List *colvalexprs; /* state for column value expressions */
List *passingvalexprs; /* state for PASSING argument expressions */
List *ns_names; /* same as TableFunc.ns_names */
List *ns_uris; /* list of states of namespace URI exprs */
Bitmapset *notnulls; /* nullability flag for each output column */

View File

@ -100,6 +100,7 @@ extern IndexInfo *makeIndexInfo(int numattrs, int numkeyattrs, Oid amoid,
bool isready, bool concurrent,
bool summarizing);
extern Node *makeStringConst(char *str, int location);
extern DefElem *makeDefElem(char *name, Node *arg, int location);
extern DefElem *makeDefElemExtended(char *nameSpace, char *name, Node *arg,
DefElemAction defaction, int location);
@ -118,5 +119,9 @@ extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
int location);
extern JsonBehavior *makeJsonBehavior(JsonBehaviorType btype, Node *expr,
int location);
extern JsonTablePath *makeJsonTablePath(Const *pathvalue, char *pathname);
extern JsonTablePathSpec *makeJsonTablePathSpec(char *string, char *name,
int string_location,
int name_location);
#endif /* MAKEFUNC_H */

View File

@ -648,6 +648,9 @@ typedef struct RangeFunction
/*
* RangeTableFunc - raw form of "table functions" such as XMLTABLE
*
* Note: JSON_TABLE is also a "table function", but it uses JsonTable node,
* not RangeTableFunc.
*/
typedef struct RangeTableFunc
{
@ -1786,6 +1789,69 @@ typedef struct JsonFuncExpr
int location; /* token location, or -1 if unknown */
} JsonFuncExpr;
/*
* JsonTablePathSpec
* untransformed specification of JSON path expression with an optional
* name
*/
typedef struct JsonTablePathSpec
{
NodeTag type;
Node *string;
char *name;
int name_location;
int location; /* location of 'string' */
} JsonTablePathSpec;
/*
* JsonTable -
* untransformed representation of JSON_TABLE
*/
typedef struct JsonTable
{
NodeTag type;
JsonValueExpr *context_item; /* context item expression */
JsonTablePathSpec *pathspec; /* JSON path specification */
List *passing; /* list of PASSING clause arguments, if any */
List *columns; /* list of JsonTableColumn */
JsonBehavior *on_error; /* ON ERROR behavior */
Alias *alias; /* table alias in FROM clause */
bool lateral; /* does it have LATERAL prefix? */
int location; /* token location, or -1 if unknown */
} JsonTable;
/*
* JsonTableColumnType -
* enumeration of JSON_TABLE column types
*/
typedef enum JsonTableColumnType
{
JTC_FOR_ORDINALITY,
JTC_REGULAR,
JTC_EXISTS,
JTC_FORMATTED,
} JsonTableColumnType;
/*
* 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 */
JsonTablePathSpec *pathspec; /* JSON path specification */
JsonFormat *format; /* JSON format clause, if specified */
JsonWrapper wrapper; /* WRAPPER behavior for formatted columns */
JsonQuotes quotes; /* omit or keep quotes on scalar strings? */
JsonBehavior *on_empty; /* ON EMPTY behavior */
JsonBehavior *on_error; /* ON ERROR behavior */
int location; /* token location, or -1 if unknown */
} JsonTableColumn;
/*
* JsonKeyValue -
* untransformed representation of JSON object key-value pair for

View File

@ -94,8 +94,14 @@ typedef struct RangeVar
ParseLoc location;
} 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 and JSON_TABLE.
*
* Entries in the ns_names list are either String nodes containing
* literal namespace names, or NULL pointers to represent DEFAULT.
@ -103,6 +109,8 @@ typedef struct RangeVar
typedef struct TableFunc
{
NodeTag type;
/* XMLTABLE or JSON_TABLE */
TableFuncType functype;
/* list of namespace URI expressions */
List *ns_uris pg_node_attr(query_jumble_ignore);
/* list of namespace names or NULL */
@ -123,8 +131,14 @@ typedef struct TableFunc
List *colexprs;
/* list of column default expressions */
List *coldefexprs pg_node_attr(query_jumble_ignore);
/* JSON_TABLE: list of column value expressions */
List *colvalexprs pg_node_attr(query_jumble_ignore);
/* JSON_TABLE: list of PASSING argument expressions */
List *passingvalexprs pg_node_attr(query_jumble_ignore);
/* nullability flag for each output column */
Bitmapset *notnulls pg_node_attr(query_jumble_ignore);
/* JSON_TABLE plan */
Node *plan pg_node_attr(query_jumble_ignore);
/* counts from 0; -1 if none specified */
int ordinalitycol pg_node_attr(query_jumble_ignore);
/* token location, or -1 if unknown */
@ -1754,6 +1768,7 @@ typedef enum JsonExprOp
JSON_EXISTS_OP, /* JSON_EXISTS() */
JSON_QUERY_OP, /* JSON_QUERY() */
JSON_VALUE_OP, /* JSON_VALUE() */
JSON_TABLE_OP, /* JSON_TABLE() */
} JsonExprOp;
/*
@ -1813,6 +1828,45 @@ typedef struct JsonExpr
int location;
} JsonExpr;
/*
* JsonTablePath
* A JSON path expression to be computed as part of evaluating
* a JSON_TABLE plan node
*/
typedef struct JsonTablePath
{
NodeTag type;
Const *value;
char *name;
} JsonTablePath;
/*
* JsonTablePlan -
* Abstract class to represent different types of JSON_TABLE "plans".
* A plan is used to generate a "row pattern" value by evaluating a JSON
* path expression against an input JSON document, which is then used for
* populating JSON_TABLE() columns
*/
typedef struct JsonTablePlan
{
pg_node_attr(abstract)
NodeTag type;
} JsonTablePlan;
/* JSON_TABLE plan to evaluate a JSON path expression */
typedef struct JsonTablePathScan
{
JsonTablePlan plan;
/* JSON path to evaluate */
JsonTablePath *path;
/* ERROR/EMPTY ON ERROR behavior */
bool errorOnError;
} JsonTablePathScan;
/* ----------------
* NullTest
*

View File

@ -242,6 +242,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)
@ -335,8 +336,10 @@ 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("period", PERIOD, 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)

View File

@ -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 */

View File

@ -14,6 +14,7 @@
#ifndef JSONPATH_H
#define JSONPATH_H
#include "executor/tablefunc.h"
#include "fmgr.h"
#include "nodes/pg_list.h"
#include "nodes/primnodes.h"
@ -303,4 +304,6 @@ extern Datum JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper,
extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
bool *error, List *vars);
extern PGDLLIMPORT const TableFuncRoutine JsonbTableRoutine;
#endif

View File

@ -52,6 +52,7 @@ test: sql/oldexec
test: sql/quote
test: sql/show
test: sql/sqljson
test: sql/sqljson_jsontable
test: sql/insupd
test: sql/parser
test: sql/prepareas

View File

@ -0,0 +1,143 @@
/* Processed by ecpg (regression mode) */
/* These include files are added by the preprocessor */
#include <ecpglib.h>
#include <ecpgerrno.h>
#include <sqlca.h>
/* End of automatic include section */
#define ECPGdebug(X,Y) ECPGdebug((X)+100,(Y))
#line 1 "sqljson_jsontable.pgc"
#include <stdio.h>
#line 1 "sqlca.h"
#ifndef POSTGRES_SQLCA_H
#define POSTGRES_SQLCA_H
#ifndef PGDLLIMPORT
#if defined(WIN32) || defined(__CYGWIN__)
#define PGDLLIMPORT __declspec (dllimport)
#else
#define PGDLLIMPORT
#endif /* __CYGWIN__ */
#endif /* PGDLLIMPORT */
#define SQLERRMC_LEN 150
#ifdef __cplusplus
extern "C"
{
#endif
struct sqlca_t
{
char sqlcaid[8];
long sqlabc;
long sqlcode;
struct
{
int sqlerrml;
char sqlerrmc[SQLERRMC_LEN];
} sqlerrm;
char sqlerrp[8];
long sqlerrd[6];
/* Element 0: empty */
/* 1: OID of processed tuple if applicable */
/* 2: number of rows processed */
/* after an INSERT, UPDATE or */
/* DELETE statement */
/* 3: empty */
/* 4: empty */
/* 5: empty */
char sqlwarn[8];
/* Element 0: set to 'W' if at least one other is 'W' */
/* 1: if 'W' at least one character string */
/* value was truncated when it was */
/* stored into a host variable. */
/*
* 2: if 'W' a (hopefully) non-fatal notice occurred
*/ /* 3: empty */
/* 4: empty */
/* 5: empty */
/* 6: empty */
/* 7: empty */
char sqlstate[5];
};
struct sqlca_t *ECPGget_sqlca(void);
#ifndef POSTGRES_ECPG_INTERNAL
#define sqlca (*ECPGget_sqlca())
#endif
#ifdef __cplusplus
}
#endif
#endif
#line 3 "sqljson_jsontable.pgc"
#line 1 "regression.h"
#line 4 "sqljson_jsontable.pgc"
/* exec sql whenever sqlerror sqlprint ; */
#line 6 "sqljson_jsontable.pgc"
int
main ()
{
/* exec sql begin declare section */
#line 12 "sqljson_jsontable.pgc"
int foo ;
/* exec sql end declare section */
#line 13 "sqljson_jsontable.pgc"
ECPGdebug (1, stderr);
{ ECPGconnect(__LINE__, 0, "ecpg1_regression" , NULL, NULL , NULL, 0);
#line 17 "sqljson_jsontable.pgc"
if (sqlca.sqlcode < 0) sqlprint();}
#line 17 "sqljson_jsontable.pgc"
{ ECPGsetcommit(__LINE__, "on", NULL);
#line 18 "sqljson_jsontable.pgc"
if (sqlca.sqlcode < 0) sqlprint();}
#line 18 "sqljson_jsontable.pgc"
{ ECPGdo(__LINE__, 0, 1, NULL, 0, ECPGst_normal, "select foo from json_table ( jsonb '[{\"foo\":1}]' , '$[*]' as p0 columns ( foo int ) ) jt ( foo )", ECPGt_EOIT,
ECPGt_int,&(foo),(long)1,(long)1,sizeof(int),
ECPGt_NO_INDICATOR, NULL , 0L, 0L, 0L, ECPGt_EORT);
#line 23 "sqljson_jsontable.pgc"
if (sqlca.sqlcode < 0) sqlprint();}
#line 23 "sqljson_jsontable.pgc"
printf("Found foo=%d\n", foo);
{ ECPGdisconnect(__LINE__, "CURRENT");
#line 26 "sqljson_jsontable.pgc"
if (sqlca.sqlcode < 0) sqlprint();}
#line 26 "sqljson_jsontable.pgc"
return 0;
}

View File

@ -0,0 +1,16 @@
[NO_PID]: ECPGdebug: set to 1
[NO_PID]: sqlca: code: 0, state: 00000
[NO_PID]: ECPGconnect: opening database ecpg1_regression on <DEFAULT> port <DEFAULT>
[NO_PID]: sqlca: code: 0, state: 00000
[NO_PID]: ECPGsetcommit on line 18: action "on"; connection "ecpg1_regression"
[NO_PID]: sqlca: code: 0, state: 00000
[NO_PID]: ecpg_execute on line 20: query: select foo from json_table ( jsonb '[{"foo":1}]' , '$[*]' as p0 columns ( foo int ) ) jt ( foo ); with 0 parameter(s) on connection ecpg1_regression
[NO_PID]: sqlca: code: 0, state: 00000
[NO_PID]: ecpg_execute on line 20: using PQexec
[NO_PID]: sqlca: code: 0, state: 00000
[NO_PID]: ecpg_process_output on line 20: correctly got 1 tuples with 1 fields
[NO_PID]: sqlca: code: 0, state: 00000
[NO_PID]: ecpg_get_data on line 20: RESULT: 1 offset: -1; array: no
[NO_PID]: sqlca: code: 0, state: 00000
[NO_PID]: ecpg_finish: connection ecpg1_regression closed
[NO_PID]: sqlca: code: 0, state: 00000

View File

@ -0,0 +1 @@
Found foo=1

View File

@ -24,6 +24,7 @@ TESTS = array array.c \
quote quote.c \
show show.c \
sqljson sqljson.c \
sqljson_jsontable sqljson_jsontable.c \
insupd insupd.c \
twophase twophase.c \
insupd insupd.c \

View File

@ -26,6 +26,7 @@ pgc_files = [
'show',
'sqlda',
'sqljson',
'sqljson_jsontable',
'twophase',
]

View File

@ -0,0 +1,29 @@
#include <stdio.h>
EXEC SQL INCLUDE sqlca;
exec sql include ../regression;
EXEC SQL WHENEVER SQLERROR sqlprint;
int
main ()
{
EXEC SQL BEGIN DECLARE SECTION;
int foo;
EXEC SQL END DECLARE SECTION;
ECPGdebug (1, stderr);
EXEC SQL CONNECT TO REGRESSDB1;
EXEC SQL SET AUTOCOMMIT = ON;
EXEC SQL SELECT foo INTO :foo FROM JSON_TABLE(jsonb '[{"foo":1}]', '$[*]' AS p0
COLUMNS (
foo int
)) jt (foo);
printf("Found foo=%d\n", foo);
EXEC SQL DISCONNECT;
return 0;
}

View File

@ -0,0 +1,636 @@
-- 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('[]', '$');
^
-- Only allow EMPTY and ERROR for ON ERROR
SELECT * FROM JSON_TABLE('[]', 'strict $.a' COLUMNS (js2 int PATH '$') DEFAULT 1 ON ERROR);
ERROR: invalid ON ERROR behavior
LINE 1: ...BLE('[]', 'strict $.a' COLUMNS (js2 int PATH '$') DEFAULT 1 ...
^
DETAIL: Only EMPTY or ERROR is allowed in the top-level ON ERROR clause.
SELECT * FROM JSON_TABLE('[]', 'strict $.a' COLUMNS (js2 int PATH '$') NULL ON ERROR);
ERROR: invalid ON ERROR behavior
LINE 1: ...BLE('[]', 'strict $.a' COLUMNS (js2 int PATH '$') NULL ON ER...
^
DETAIL: Only EMPTY or ERROR is allowed in the top-level ON ERROR clause.
SELECT * FROM JSON_TABLE('[]', 'strict $.a' COLUMNS (js2 int PATH '$') EMPTY ON ERROR);
js2
-----
(0 rows)
SELECT * FROM JSON_TABLE('[]', 'strict $.a' COLUMNS (js2 int PATH '$') ERROR ON ERROR);
ERROR: jsonpath member accessor can only be applied to an object
-- Column and path names must be distinct
SELECT * FROM JSON_TABLE(jsonb'"1.23"', '$.a' as js2 COLUMNS (js2 int path '$'));
ERROR: duplicate JSON_TABLE column or path name: js2
LINE 1: ...M JSON_TABLE(jsonb'"1.23"', '$.a' as js2 COLUMNS (js2 int pa...
^
-- Should fail (no columns)
SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
ERROR: syntax error at or near ")"
LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
^
SELECT * FROM JSON_TABLE (NULL::jsonb, '$' COLUMNS (v1 timestamp)) AS f (v1, v2);
ERROR: JSON_TABLE function has 1 columns available but 2 columns specified
--duplicated column name
SELECT * FROM JSON_TABLE(jsonb'"1.23"', '$.a' COLUMNS (js2 int path '$', js2 int path '$'));
ERROR: duplicate JSON_TABLE column or path name: js2
LINE 1: ...E(jsonb'"1.23"', '$.a' COLUMNS (js2 int path '$', js2 int pa...
^
--return composite data type.
create type comp as (a int, b int);
SELECT * FROM JSON_TABLE(jsonb '{"rec": "(1,2)"}', '$' COLUMNS (id FOR ORDINALITY, comp comp path '$.rec' omit quotes)) jt;
id | comp
----+-------
1 | (1,2)
(1 row)
drop type comp;
-- NULL => empty table
SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
foo
-----
(0 rows)
SELECT * FROM JSON_TABLE(jsonb'"1.23"', 'strict $.a' COLUMNS (js2 int PATH '$'));
js2
-----
(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');
CREATE TEMP TABLE json_table_test (js) AS
(VALUES
('1'),
('[]'),
('{}'),
('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
);
-- Regular "unformatted" columns
SELECT *
FROM json_table_test vals
LEFT OUTER JOIN
JSON_TABLE(
vals.js::jsonb, 'lax $[*]'
COLUMNS (
id FOR ORDINALITY,
"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 '$'
)
) jt
ON true;
js | id | int | text | char(4) | bool | numeric | domain | js | jb
---------------------------------------------------------------------------------------+----+-----+---------+---------+------+---------+---------+--------------+--------------
1 | 1 | 1 | 1 | 1 | t | 1 | 1 | 1 | 1
[] | | | | | | | | |
{} | 1 | | | | | | | {} | {}
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | 1 | 1 | 1 | t | 1 | 1 | 1 | 1
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | | 1.23 | 1.23 | | 1.23 | 1.23 | 1.23 | 1.23
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | 2 | 2 | 2 | | 2 | 2 | "2" | "2"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | | aaaaaaa | aaaa | | | aaaaaaa | "aaaaaaa" | "aaaaaaa"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | | foo | foo | | | | "foo" | "foo"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | | | | | | | null | null
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | | f | f | f | | f | false | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | | t | t | t | | t | true | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | | | | | | | {"aaa": 123} | {"aaa": 123}
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | | [1,2] | [1,2 | | | [1,2] | "[1,2]" | "[1,2]"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | | "str" | "str | | | "str" | "\"str\"" | "\"str\""
(14 rows)
-- "formatted" columns
SELECT *
FROM json_table_test vals
LEFT OUTER JOIN
JSON_TABLE(
vals.js::jsonb, 'lax $[*]'
COLUMNS (
id FOR ORDINALITY,
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
)
) jt
ON true;
js | id | jst | jsc | jsv | jsb | jsbq
---------------------------------------------------------------------------------------+----+--------------+------+------+--------------+--------------
1 | 1 | 1 | 1 | 1 | 1 | 1
[] | | | | | |
{} | 1 | {} | {} | {} | {} | {}
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | 1 | 1 | 1 | 1 | 1
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | 1.23 | 1.23 | 1.23 | 1.23 | 1.23
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | "2" | "2" | "2" | "2" | 2
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | "aaaaaaa" | "aaa | "aaa | "aaaaaaa" |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | "foo" | "foo | "foo | "foo" |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | null | null | null | null | null
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | false | fals | fals | false | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | true | true | true | true | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123}
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | "[1,2]" | "[1, | "[1, | "[1,2]" | [1, 2]
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | "\"str\"" | "\"s | "\"s | "\"str\"" | "str"
(14 rows)
-- EXISTS columns
SELECT *
FROM json_table_test vals
LEFT OUTER JOIN
JSON_TABLE(
vals.js::jsonb, 'lax $[*]'
COLUMNS (
id FOR ORDINALITY,
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
)
) jt
ON true;
js | id | exists1 | exists2 | exists3 | exists4
---------------------------------------------------------------------------------------+----+---------+---------+---------+---------
1 | 1 | f | 0 | | false
[] | | | | |
{} | 1 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 1 | 1 | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | f | 0 | | false
(14 rows)
-- Other miscellaneous checks
SELECT *
FROM json_table_test vals
LEFT OUTER JOIN
JSON_TABLE(
vals.js::jsonb, 'lax $[*]'
COLUMNS (
id FOR ORDINALITY,
aaa int, -- "aaa" has implicit path '$."aaa"'
aaa1 int PATH '$.aaa',
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 | aaa | aaa1 | js2 | jsb2w | jsb2q | ia | ta | jba
---------------------------------------------------------------------------------------+----+-----+------+--------------+----------------+--------------+----+----+-----
1 | 1 | | | 1 | [1] | 1 | | |
[] | | | | | | | | |
{} | 1 | | | {} | [{}] | {} | | |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | | | 1 | [1] | 1 | | |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | | | 1.23 | [1.23] | 1.23 | | |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | | | "2" | ["2"] | 2 | | |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | | | "aaaaaaa" | ["aaaaaaa"] | | | |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | | | "foo" | ["foo"] | | | |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | | | null | [null] | null | | |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | | | false | [false] | false | | |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | | | true | [true] | true | | |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | 123 | 123 | {"aaa": 123} | [{"aaa": 123}] | {"aaa": 123} | | |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | | | "[1,2]" | ["[1,2]"] | [1, 2] | | |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | | | "\"str\"" | ["\"str\""] | "str" | | |
(14 rows)
-- JSON_TABLE: Test backward parsing
CREATE VIEW jsonb_table_view2 AS
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
"int" int PATH '$',
"text" text PATH '$',
"char(4)" char(4) PATH '$',
"bool" bool PATH '$',
"numeric" numeric PATH '$',
"domain" jsonb_test_domain PATH '$'));
CREATE VIEW jsonb_table_view3 AS
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
js json PATH '$',
jb jsonb PATH '$',
jst text FORMAT JSON PATH '$',
jsc char(4) FORMAT JSON PATH '$',
jsv varchar(4) FORMAT JSON PATH '$'));
CREATE VIEW jsonb_table_view4 AS
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
jsb jsonb FORMAT JSON PATH '$',
jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
aaa int, -- implicit path '$."aaa"',
aaa1 int PATH '$.aaa'));
CREATE VIEW jsonb_table_view5 AS
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
exists1 bool EXISTS PATH '$.aaa',
exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR));
CREATE VIEW jsonb_table_view6 AS
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
js2 json PATH '$',
jsb2w jsonb PATH '$' WITH WRAPPER,
jsb2q jsonb PATH '$' OMIT QUOTES,
ia int[] PATH '$',
ta text[] PATH '$',
jba jsonb[] PATH '$'));
\sv jsonb_table_view2
CREATE OR REPLACE VIEW public.jsonb_table_view2 AS
SELECT "int",
text,
"char(4)",
bool,
"numeric",
domain
FROM JSON_TABLE(
'null'::jsonb, '$[*]' AS json_table_path_0
PASSING
1 + 2 AS a,
'"foo"'::json AS "b c"
COLUMNS (
"int" integer PATH '$',
text text PATH '$',
"char(4)" character(4) PATH '$',
bool boolean PATH '$',
"numeric" numeric PATH '$',
domain jsonb_test_domain PATH '$'
)
)
\sv jsonb_table_view3
CREATE OR REPLACE VIEW public.jsonb_table_view3 AS
SELECT js,
jb,
jst,
jsc,
jsv
FROM JSON_TABLE(
'null'::jsonb, '$[*]' AS json_table_path_0
PASSING
1 + 2 AS a,
'"foo"'::json AS "b c"
COLUMNS (
js json PATH '$',
jb jsonb PATH '$',
jst text FORMAT JSON PATH '$',
jsc character(4) FORMAT JSON PATH '$',
jsv character varying(4) FORMAT JSON PATH '$'
)
)
\sv jsonb_table_view4
CREATE OR REPLACE VIEW public.jsonb_table_view4 AS
SELECT jsb,
jsbq,
aaa,
aaa1
FROM JSON_TABLE(
'null'::jsonb, '$[*]' AS json_table_path_0
PASSING
1 + 2 AS a,
'"foo"'::json AS "b c"
COLUMNS (
jsb jsonb PATH '$',
jsbq jsonb PATH '$' OMIT QUOTES,
aaa integer PATH '$."aaa"',
aaa1 integer PATH '$."aaa"'
)
)
\sv jsonb_table_view5
CREATE OR REPLACE VIEW public.jsonb_table_view5 AS
SELECT exists1,
exists2,
exists3
FROM JSON_TABLE(
'null'::jsonb, '$[*]' AS json_table_path_0
PASSING
1 + 2 AS a,
'"foo"'::json AS "b c"
COLUMNS (
exists1 boolean EXISTS PATH '$."aaa"',
exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR,
exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR
)
)
\sv jsonb_table_view6
CREATE OR REPLACE VIEW public.jsonb_table_view6 AS
SELECT js2,
jsb2w,
jsb2q,
ia,
ta,
jba
FROM JSON_TABLE(
'null'::jsonb, '$[*]' AS json_table_path_0
PASSING
1 + 2 AS a,
'"foo"'::json AS "b c"
COLUMNS (
js2 json PATH '$',
jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER,
jsb2q jsonb PATH '$' OMIT QUOTES,
ia integer[] PATH '$',
ta text[] PATH '$',
jba jsonb[] PATH '$'
)
)
EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view2;
QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Table Function Scan on "json_table"
Output: "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain
Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_0 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS ("int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$'))
(3 rows)
EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view3;
QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Table Function Scan on "json_table"
Output: "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv
Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_0 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$'))
(3 rows)
EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view4;
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Table Function Scan on "json_table"
Output: "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1
Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_0 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"'))
(3 rows)
EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view5;
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Table Function Scan on "json_table"
Output: "json_table".exists1, "json_table".exists2, "json_table".exists3
Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_0 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR))
(3 rows)
EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view6;
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Table Function Scan on "json_table"
Output: "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba
Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_0 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$'))
(3 rows)
-- JSON_TABLE() with alias
EXPLAIN (COSTS OFF, VERBOSE)
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
id FOR ORDINALITY,
"int" int PATH '$',
"text" text PATH '$'
)) json_table_func;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Table Function Scan on "json_table" json_table_func
Output: id, "int", text
Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_0 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, "int" integer PATH '$', text text PATH '$'))
(3 rows)
EXPLAIN (COSTS OFF, FORMAT JSON, VERBOSE)
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
id FOR ORDINALITY,
"int" int PATH '$',
"text" text PATH '$'
)) json_table_func;
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
[ +
{ +
"Plan": { +
"Node Type": "Table Function Scan", +
"Parallel Aware": false, +
"Async Capable": false, +
"Table Function Name": "json_table", +
"Alias": "json_table_func", +
"Output": ["id", "\"int\"", "text"], +
"Table Function Call": "JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_0 PASSING 3 AS a, '\"foo\"'::jsonb AS \"b c\" COLUMNS (id FOR ORDINALITY, \"int\" integer PATH '$', text text PATH '$'))"+
} +
} +
]
(1 row)
DROP VIEW jsonb_table_view2;
DROP VIEW jsonb_table_view3;
DROP VIEW jsonb_table_view4;
DROP VIEW jsonb_table_view5;
DROP VIEW jsonb_table_view6;
DROP DOMAIN jsonb_test_domain;
-- JSON_TABLE: only one FOR ORDINALITY columns allowed
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, a int PATH '$.a' ERROR ON EMPTY)) jt;
ERROR: cannot use more than one FOR ORDINALITY column
LINE 1: ..._TABLE(jsonb '1', '$' COLUMNS (id FOR ORDINALITY, id2 FOR OR...
^
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (id FOR ORDINALITY, a int PATH '$' ERROR ON EMPTY)) jt;
id | a
----+---
1 | 1
(1 row)
-- 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"
-- TABLE-level ERROR ON ERROR is not propagated to columns
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;
ERROR: no SQL/JSON item
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON ERROR) 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: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
item
---------
"world"
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' OMIT QUOTES ON SCALAR STRING));
item
-------
world
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text FORMAT JSON PATH '$' KEEP QUOTES));
item
---------
"world"
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text FORMAT JSON PATH '$' OMIT QUOTES));
item
-------
world
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text FORMAT JSON PATH '$' WITHOUT WRAPPER KEEP QUOTES));
item
---------
"world"
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' WITHOUT WRAPPER OMIT QUOTES));
item
-------
world
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text FORMAT JSON PATH '$' WITH WRAPPER));
item
-----------
["world"]
(1 row)
-- Error: QUOTES clause meaningless when WITH WRAPPER is present
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text FORMAT JSON PATH '$' WITH WRAPPER KEEP QUOTES));
ERROR: SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
LINE 1: ...T * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text ...
^
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' WITH WRAPPER OMIT QUOTES));
ERROR: SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
LINE 1: ...T * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text ...
^
-- Test PASSING args
SELECT *
FROM JSON_TABLE(
jsonb '[1,2,3]',
'$[*] ? (@ < $x)'
PASSING 3 AS x
COLUMNS (y text FORMAT JSON PATH '$')
) jt;
y
---
1
2
(2 rows)
-- PASSING arguments are also passed to column paths
SELECT *
FROM JSON_TABLE(
jsonb '[1,2,3]',
'$[*] ? (@ < $x)'
PASSING 10 AS x, 3 AS y
COLUMNS (a text FORMAT JSON PATH '$ ? (@ < $y)')
) jt;
a
---
1
2
(3 rows)
-- Should fail (not supported)
SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
ERROR: only string constants are supported in JSON_TABLE path specification
LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
^

View File

@ -103,7 +103,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 sqljson sqljson_queryfuncs
test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath sqljson sqljson_queryfuncs sqljson_jsontable
# ----------
# Another group of parallel tests

View File

@ -0,0 +1,290 @@
-- JSON_TABLE
-- Should fail (JSON_TABLE can be used only in FROM clause)
SELECT JSON_TABLE('[]', '$');
-- Only allow EMPTY and ERROR for ON ERROR
SELECT * FROM JSON_TABLE('[]', 'strict $.a' COLUMNS (js2 int PATH '$') DEFAULT 1 ON ERROR);
SELECT * FROM JSON_TABLE('[]', 'strict $.a' COLUMNS (js2 int PATH '$') NULL ON ERROR);
SELECT * FROM JSON_TABLE('[]', 'strict $.a' COLUMNS (js2 int PATH '$') EMPTY ON ERROR);
SELECT * FROM JSON_TABLE('[]', 'strict $.a' COLUMNS (js2 int PATH '$') ERROR ON ERROR);
-- Column and path names must be distinct
SELECT * FROM JSON_TABLE(jsonb'"1.23"', '$.a' as js2 COLUMNS (js2 int path '$'));
-- Should fail (no columns)
SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
SELECT * FROM JSON_TABLE (NULL::jsonb, '$' COLUMNS (v1 timestamp)) AS f (v1, v2);
--duplicated column name
SELECT * FROM JSON_TABLE(jsonb'"1.23"', '$.a' COLUMNS (js2 int path '$', js2 int path '$'));
--return composite data type.
create type comp as (a int, b int);
SELECT * FROM JSON_TABLE(jsonb '{"rec": "(1,2)"}', '$' COLUMNS (id FOR ORDINALITY, comp comp path '$.rec' omit quotes)) jt;
drop type comp;
-- NULL => empty table
SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
SELECT * FROM JSON_TABLE(jsonb'"1.23"', 'strict $.a' COLUMNS (js2 int PATH '$'));
--
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');
CREATE TEMP TABLE json_table_test (js) AS
(VALUES
('1'),
('[]'),
('{}'),
('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
);
-- Regular "unformatted" columns
SELECT *
FROM json_table_test vals
LEFT OUTER JOIN
JSON_TABLE(
vals.js::jsonb, 'lax $[*]'
COLUMNS (
id FOR ORDINALITY,
"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 '$'
)
) jt
ON true;
-- "formatted" columns
SELECT *
FROM json_table_test vals
LEFT OUTER JOIN
JSON_TABLE(
vals.js::jsonb, 'lax $[*]'
COLUMNS (
id FOR ORDINALITY,
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
)
) jt
ON true;
-- EXISTS columns
SELECT *
FROM json_table_test vals
LEFT OUTER JOIN
JSON_TABLE(
vals.js::jsonb, 'lax $[*]'
COLUMNS (
id FOR ORDINALITY,
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
)
) jt
ON true;
-- Other miscellaneous checks
SELECT *
FROM json_table_test vals
LEFT OUTER JOIN
JSON_TABLE(
vals.js::jsonb, 'lax $[*]'
COLUMNS (
id FOR ORDINALITY,
aaa int, -- "aaa" has implicit path '$."aaa"'
aaa1 int PATH '$.aaa',
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_view2 AS
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
"int" int PATH '$',
"text" text PATH '$',
"char(4)" char(4) PATH '$',
"bool" bool PATH '$',
"numeric" numeric PATH '$',
"domain" jsonb_test_domain PATH '$'));
CREATE VIEW jsonb_table_view3 AS
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
js json PATH '$',
jb jsonb PATH '$',
jst text FORMAT JSON PATH '$',
jsc char(4) FORMAT JSON PATH '$',
jsv varchar(4) FORMAT JSON PATH '$'));
CREATE VIEW jsonb_table_view4 AS
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
jsb jsonb FORMAT JSON PATH '$',
jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
aaa int, -- implicit path '$."aaa"',
aaa1 int PATH '$.aaa'));
CREATE VIEW jsonb_table_view5 AS
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
exists1 bool EXISTS PATH '$.aaa',
exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR));
CREATE VIEW jsonb_table_view6 AS
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
js2 json PATH '$',
jsb2w jsonb PATH '$' WITH WRAPPER,
jsb2q jsonb PATH '$' OMIT QUOTES,
ia int[] PATH '$',
ta text[] PATH '$',
jba jsonb[] PATH '$'));
\sv jsonb_table_view2
\sv jsonb_table_view3
\sv jsonb_table_view4
\sv jsonb_table_view5
\sv jsonb_table_view6
EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view2;
EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view3;
EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view4;
EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view5;
EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view6;
-- JSON_TABLE() with alias
EXPLAIN (COSTS OFF, VERBOSE)
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
id FOR ORDINALITY,
"int" int PATH '$',
"text" text PATH '$'
)) json_table_func;
EXPLAIN (COSTS OFF, FORMAT JSON, VERBOSE)
SELECT * FROM
JSON_TABLE(
jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
COLUMNS (
id FOR ORDINALITY,
"int" int PATH '$',
"text" text PATH '$'
)) json_table_func;
DROP VIEW jsonb_table_view2;
DROP VIEW jsonb_table_view3;
DROP VIEW jsonb_table_view4;
DROP VIEW jsonb_table_view5;
DROP VIEW jsonb_table_view6;
DROP DOMAIN jsonb_test_domain;
-- JSON_TABLE: only one FOR ORDINALITY columns allowed
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, a int PATH '$.a' ERROR ON EMPTY)) jt;
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (id FOR ORDINALITY, a int PATH '$' ERROR ON EMPTY)) jt;
-- 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;
-- TABLE-level ERROR ON ERROR is not propagated to columns
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 ERROR) 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: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' OMIT QUOTES ON SCALAR STRING));
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text FORMAT JSON PATH '$' KEEP QUOTES));
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text FORMAT JSON PATH '$' OMIT QUOTES));
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text FORMAT JSON PATH '$' WITHOUT WRAPPER KEEP QUOTES));
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' WITHOUT WRAPPER OMIT QUOTES));
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text FORMAT JSON PATH '$' WITH WRAPPER));
-- Error: QUOTES clause meaningless when WITH WRAPPER is present
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text FORMAT JSON PATH '$' WITH WRAPPER KEEP QUOTES));
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' WITH WRAPPER OMIT QUOTES));
-- Test PASSING args
SELECT *
FROM JSON_TABLE(
jsonb '[1,2,3]',
'$[*] ? (@ < $x)'
PASSING 3 AS x
COLUMNS (y text FORMAT JSON PATH '$')
) jt;
-- PASSING arguments are also passed to column paths
SELECT *
FROM JSON_TABLE(
jsonb '[1,2,3]',
'$[*] ? (@ < $x)'
PASSING 10 AS x, 3 AS y
COLUMNS (a text FORMAT JSON PATH '$ ? (@ < $y)')
) jt;
-- Should fail (not supported)
SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));

View File

@ -1341,6 +1341,17 @@ JsonReturning
JsonScalarExpr
JsonSemAction
JsonSerializeExpr
JsonTable
JsonTableColumn
JsonTableColumnType
JsonTableExecContext
JsonTableParseContext
JsonTablePath
JsonTablePathScan
JsonTablePathSpec
JsonTablePlan
JsonTablePlanRowSource
JsonTablePlanState
JsonTokenType
JsonTransformStringValuesAction
JsonTypeCategory
@ -2821,6 +2832,7 @@ TableFunc
TableFuncRoutine
TableFuncScan
TableFuncScanState
TableFuncType
TableInfo
TableLikeClause
TableSampleClause