mirror of https://github.com/postgres/postgres
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
pull/159/head
parent
a9d6c38684
commit
de3600452b
@ -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; |
||||||
|
} |
@ -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; |
||||||
|
} |
@ -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 |
@ -0,0 +1 @@ |
|||||||
|
Found foo=1 |
@ -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; |
||||||
|
} |
@ -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}', '$' || '.' || '... |
||||||
|
^ |
@ -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)); |
Loading…
Reference in new issue