From 6185c9737cf48c9540782d88f12bd2912d6ca1cc Mon Sep 17 00:00:00 2001 From: Amit Langote Date: Thu, 21 Mar 2024 17:06:27 +0900 Subject: [PATCH] Add SQL/JSON query functions MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit This introduces the following SQL/JSON functions for querying JSON data using jsonpath expressions: JSON_EXISTS(), which can be used to apply a jsonpath expression to a JSON value to check if it yields any values. JSON_QUERY(), which can be used to to apply a jsonpath expression to a JSON value to get a JSON object, an array, or a string. There are various options to control whether multi-value result uses array wrappers and whether the singleton scalar strings are quoted or not. JSON_VALUE(), which can be used to apply a jsonpath expression to a JSON value to return a single scalar value, producing an error if it multiple values are matched. Both JSON_VALUE() and JSON_QUERY() functions have options for handling EMPTY and ERROR conditions, which can be used to specify the behavior when no values are matched and when an error occurs during jsonpath evaluation, respectively. Author: Nikita Glukhov Author: Teodor Sigaev Author: Oleg Bartunov Author: Alexander Korotkov Author: Andrew Dunstan Author: Amit Langote Author: Peter Eisentraut Author: Jian He 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, Anton A. Melnikov, Nikita Malakhov, Peter Eisentraut, Tomas Vondra 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+HiwqHROpf9e644D8BRqYvaAPmgBZVup-xKMDPk-nd4EpgzHw@mail.gmail.com Discussion: https://postgr.es/m/CA+HiwqE4XTdfb1nW=Ojoy_tQSRhYt-q_kb6i5d4xcKyrLC1Nbg@mail.gmail.com --- doc/src/sgml/func.sgml | 210 +++ src/backend/catalog/sql_features.txt | 12 +- src/backend/executor/execExpr.c | 301 ++++ src/backend/executor/execExprInterp.c | 338 ++++- src/backend/jit/llvm/llvmjit_expr.c | 108 ++ src/backend/jit/llvm/llvmjit_types.c | 3 + src/backend/nodes/makefuncs.c | 16 + src/backend/nodes/nodeFuncs.c | 159 +++ src/backend/optimizer/path/costsize.c | 3 +- src/backend/optimizer/util/clauses.c | 20 + src/backend/parser/gram.y | 188 ++- src/backend/parser/parse_expr.c | 553 ++++++- src/backend/parser/parse_target.c | 18 + src/backend/utils/adt/formatting.c | 44 + src/backend/utils/adt/jsonb.c | 31 + src/backend/utils/adt/jsonfuncs.c | 62 +- src/backend/utils/adt/jsonpath.c | 281 ++++ src/backend/utils/adt/jsonpath_exec.c | 322 +++++ src/backend/utils/adt/ruleutils.c | 138 ++ src/include/executor/execExpr.h | 22 + src/include/nodes/execnodes.h | 73 + src/include/nodes/makefuncs.h | 2 + src/include/nodes/parsenodes.h | 42 + src/include/nodes/primnodes.h | 122 ++ src/include/parser/kwlist.h | 11 + src/include/utils/formatting.h | 1 + src/include/utils/jsonb.h | 1 + src/include/utils/jsonfuncs.h | 7 + src/include/utils/jsonpath.h | 24 + src/interfaces/ecpg/preproc/ecpg.trailer | 28 + .../regress/expected/sqljson_queryfuncs.out | 1269 +++++++++++++++++ src/test/regress/parallel_schedule | 2 +- src/test/regress/sql/sqljson_queryfuncs.sql | 428 ++++++ src/tools/pgindent/typedefs.list | 12 + 34 files changed, 4815 insertions(+), 36 deletions(-) create mode 100644 src/test/regress/expected/sqljson_queryfuncs.out create mode 100644 src/test/regress/sql/sqljson_queryfuncs.sql diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index 030ea8affd..8ecc02f2b9 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -15488,6 +15488,11 @@ table2-mapping the SQL/JSON path language + + + the SQL/JSON query functions + + @@ -18616,6 +18621,211 @@ $.* ? (@ like_regex "^\\d+$") + + + SQL/JSON Query Functions + + SQL/JSON functions JSON_EXISTS(), + JSON_QUERY(), and JSON_VALUE() + described in can be used + to query JSON documents. Each of these functions apply a + path_expression (the query) to a + context_item (the document); see + for more details on what + path_expression can contain. + + + + SQL/JSON Query Functions + + + + + Function signature + + + Description + + + Example(s) + + + + + + + json_exists + json_exists ( + context_item, path_expression PASSING { value AS varname } , ... + { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR ) + + + Returns true if the SQL/JSON path_expression + applied to the context_item using the + PASSING values yields any + items. + + + The ON ERROR clause specifies the behavior if + an error occurs; the default is to return the boolean + FALSE value. Note that if the + path_expression is strict + and ON ERROR behavior is ERROR, + an error is generated if it yields no items. + + + Examples: + + + select json_exists(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)') + t + + + select json_exists(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR) + f + + + select json_exists(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR) + + +ERROR: jsonpath array subscript is out of bounds + + + + + + json_query + json_query ( + context_item, path_expression PASSING { value AS varname } , ... + RETURNING data_type FORMAT JSON ENCODING UTF8 + { WITHOUT | WITH { CONDITIONAL | UNCONDITIONAL } } ARRAY WRAPPER + { KEEP | OMIT } QUOTES ON SCALAR STRING + { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT expression } ON EMPTY + { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT expression } ON ERROR ) + + + Returns the result of applying the SQL/JSON + path_expression to the + context_item using the + PASSING values. + + + If the path expression returns multiple SQL/JSON items, it might be + necessary to wrap the result using the WITH WRAPPER + clause to make it a valid JSON string. If the wrapper is + UNCONDITIONAL, an array wrapper will always be + applied, even if the returned value is already a single JSON object + or an array. If it is CONDITIONAL, it will not be + applied to a single JSON object or an array. + UNCONDITIONAL is the default. + + + If the result is a scalar string, by default, the returned value will + be surrounded by quotes, making it a valid JSON value. It can be made + explicit by specifying KEEP QUOTES. Conversely, + quotes can be omitted by specifying OMIT QUOTES. + Note that OMIT QUOTES cannot be specified when + WITH WRAPPER is also specified. + + + The RETURNING clause can be used to specify the + data_type of the result value. By default, + the returned value will be of type jsonb. + + + The ON EMPTY clause specifies the behavior if + evaluating path_expression yields no value + at all. The default when ON EMPTY is not specified + is to return a null value. + + + The ON ERROR clause specifies the + behavior if an error occurs when evaluating + path_expression, including the operation to + coerce the result value to the output type, or during the execution of + ON EMPTY behavior (that is caused by empty result + of path_expression evaluation). The default + when ON ERROR is not specified is to return a null + value. + + + Examples: + + + select json_query(jsonb '[1,[2,3],null]', 'lax $[*][1]' WITH CONDITIONAL WRAPPER) + [3] + + + select json_query(jsonb '{"a": "[1, 2]"}', 'lax $.a' OMIT QUOTES); + [1, 2] + + + select json_query(jsonb '{"a": "[1, 2]"}', 'lax $.a' RETURNING int[] OMIT QUOTES ERROR ON ERROR); + + +ERROR: malformed array literal: "[1, 2]" +DETAIL: Missing "]" after array dimensions. + + + + + + + json_value + json_value ( + context_item, path_expression + PASSING { value AS varname } , ... + RETURNING data_type + { ERROR | NULL | DEFAULT expression } ON EMPTY + { ERROR | NULL | DEFAULT expression } ON ERROR ) + + + Returns the result of applying the SQL/JSON + path_expression to the + context_item using the + PASSING values. + + + The extracted value must be a single SQL/JSON + scalar item; an error is thrown if that's not the case. If you expect + that extracted value might be an object or an array, use the + json_query function instead. + + + The RETURNING clause can be used to specify the + data_type of the result value. By default, + the returned value will be of type text. + + + The ON ERROR and ON EMPTY + clauses have similar semantics as mentioned in the description of + json_query. + + + Note that scalar strings returned by json_value + always have their quotes removed, equivalent to specifying + OMIT QUOTES in json_query. + + + Examples: + + + select json_value(jsonb '"123.45"', '$' RETURNING float) + 123.45 + + + select json_value(jsonb '"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date) + 2015-02-01 + + + select json_value(jsonb '[1,2]', 'strict $[*]' DEFAULT 9 ON ERROR) + 9 + + + + +
+
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt index 925d15a2c3..80ac59fba4 100644 --- a/src/backend/catalog/sql_features.txt +++ b/src/backend/catalog/sql_features.txt @@ -547,15 +547,15 @@ T811 Basic SQL/JSON constructor functions YES T812 SQL/JSON: JSON_OBJECTAGG YES T813 SQL/JSON: JSON_ARRAYAGG with ORDER BY YES T814 Colon in JSON_OBJECT or JSON_OBJECTAGG YES -T821 Basic SQL/JSON query operators NO +T821 Basic SQL/JSON query operators YES T822 SQL/JSON: IS JSON WITH UNIQUE KEYS predicate YES -T823 SQL/JSON: PASSING clause NO +T823 SQL/JSON: PASSING clause YES T824 JSON_TABLE: specific PLAN clause NO -T825 SQL/JSON: ON EMPTY and ON ERROR clauses NO -T826 General value expression in ON ERROR or ON EMPTY clauses NO +T825 SQL/JSON: ON EMPTY and ON ERROR clauses YES +T826 General value expression in ON ERROR or ON EMPTY clauses YES T827 JSON_TABLE: sibling NESTED COLUMNS clauses NO -T828 JSON_QUERY NO -T829 JSON_QUERY: array wrapper options NO +T828 JSON_QUERY YES +T829 JSON_QUERY: array wrapper options YES T830 Enforcing unique keys in SQL/JSON constructor functions YES T831 SQL/JSON path language: strict mode YES T832 SQL/JSON path language: item method YES diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c index 728c8d5fda..bc5feb0115 100644 --- a/src/backend/executor/execExpr.c +++ b/src/backend/executor/execExpr.c @@ -48,6 +48,7 @@ #include "utils/array.h" #include "utils/builtins.h" #include "utils/jsonfuncs.h" +#include "utils/jsonpath.h" #include "utils/lsyscache.h" #include "utils/typcache.h" @@ -87,6 +88,12 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate, FunctionCallInfo fcinfo, AggStatePerTrans pertrans, int transno, int setno, int setoff, bool ishash, bool nullcheck); +static void ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state, + Datum *resv, bool *resnull, + ExprEvalStep *scratch); +static void ExecInitJsonCoercion(ExprState *state, JsonReturning *returning, + ErrorSaveContext *escontext, + Datum *resv, bool *resnull); /* @@ -2425,6 +2432,14 @@ ExecInitExprRec(Expr *node, ExprState *state, break; } + case T_JsonExpr: + { + JsonExpr *jsexpr = castNode(JsonExpr, node); + + ExecInitJsonExpr(jsexpr, state, resv, resnull, &scratch); + break; + } + case T_NullTest: { NullTest *ntest = (NullTest *) node; @@ -4193,3 +4208,289 @@ ExecBuildParamSetEqual(TupleDesc desc, return state; } + +/* + * Push steps to evaluate a JsonExpr and its various subsidiary expressions. + */ +static void +ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state, + Datum *resv, bool *resnull, + ExprEvalStep *scratch) +{ + JsonExprState *jsestate = palloc0(sizeof(JsonExprState)); + ListCell *argexprlc; + ListCell *argnamelc; + List *jumps_return_null = NIL; + List *jumps_to_end = NIL; + ListCell *lc; + ErrorSaveContext *escontext = + jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR ? + &jsestate->escontext : NULL; + + jsestate->jsexpr = jsexpr; + + /* + * Evaluate formatted_expr storing the result into + * jsestate->formatted_expr. + */ + ExecInitExprRec((Expr *) jsexpr->formatted_expr, state, + &jsestate->formatted_expr.value, + &jsestate->formatted_expr.isnull); + + /* JUMP to return NULL if formatted_expr evaluates to NULL */ + jumps_return_null = lappend_int(jumps_return_null, state->steps_len); + scratch->opcode = EEOP_JUMP_IF_NULL; + scratch->resnull = &jsestate->formatted_expr.isnull; + scratch->d.jump.jumpdone = -1; /* set below */ + ExprEvalPushStep(state, scratch); + + /* + * Evaluate pathspec expression storing the result into + * jsestate->pathspec. + */ + ExecInitExprRec((Expr *) jsexpr->path_spec, state, + &jsestate->pathspec.value, + &jsestate->pathspec.isnull); + + /* JUMP to return NULL if path_spec evaluates to NULL */ + jumps_return_null = lappend_int(jumps_return_null, state->steps_len); + scratch->opcode = EEOP_JUMP_IF_NULL; + scratch->resnull = &jsestate->pathspec.isnull; + scratch->d.jump.jumpdone = -1; /* set below */ + ExprEvalPushStep(state, scratch); + + /* Steps to compute PASSING args. */ + jsestate->args = NIL; + forboth(argexprlc, jsexpr->passing_values, + argnamelc, jsexpr->passing_names) + { + Expr *argexpr = (Expr *) lfirst(argexprlc); + String *argname = lfirst_node(String, argnamelc); + JsonPathVariable *var = palloc(sizeof(*var)); + + var->name = argname->sval; + var->typid = exprType((Node *) argexpr); + var->typmod = exprTypmod((Node *) argexpr); + + ExecInitExprRec((Expr *) argexpr, state, &var->value, &var->isnull); + + jsestate->args = lappend(jsestate->args, var); + } + + /* Step for jsonpath evaluation; see ExecEvalJsonExprPath(). */ + scratch->opcode = EEOP_JSONEXPR_PATH; + scratch->resvalue = resv; + scratch->resnull = resnull; + scratch->d.jsonexpr.jsestate = jsestate; + ExprEvalPushStep(state, scratch); + + /* + * Step to return NULL after jumping to skip the EEOP_JSONEXPR_PATH step + * when either formatted_expr or pathspec is NULL. Adjust jump target + * addresses of JUMPs that we added above. + */ + foreach(lc, jumps_return_null) + { + ExprEvalStep *as = &state->steps[lfirst_int(lc)]; + + as->d.jump.jumpdone = state->steps_len; + } + scratch->opcode = EEOP_CONST; + scratch->resvalue = resv; + scratch->resnull = resnull; + scratch->d.constval.value = (Datum) 0; + scratch->d.constval.isnull = true; + ExprEvalPushStep(state, scratch); + + /* + * Jump to coerce the NULL using coercion_expr if present. Coercing NULL + * is only interesting when the RETURNING type is a domain whose + * constraints must be checked. jsexpr->coercion_expr containing a + * CoerceToDomain node must have been set in that case. + */ + if (jsexpr->coercion_expr) + { + scratch->opcode = EEOP_JUMP; + scratch->d.jump.jumpdone = state->steps_len + 1; + ExprEvalPushStep(state, scratch); + } + + /* + * To handle coercion errors softly, use the following ErrorSaveContext to + * pass to ExecInitExprRec() when initializing the coercion expressions + * and in the EEOP_JSONEXPR_COERCION step. + */ + jsestate->escontext.type = T_ErrorSaveContext; + + /* + * Steps to coerce the result value computed by EEOP_JSONEXPR_PATH or the + * NULL returned on NULL input as described above. + */ + jsestate->jump_eval_coercion = -1; + if (jsexpr->coercion_expr) + { + Datum *save_innermost_caseval; + bool *save_innermost_casenull; + ErrorSaveContext *save_escontext; + + jsestate->jump_eval_coercion = state->steps_len; + + save_innermost_caseval = state->innermost_caseval; + save_innermost_casenull = state->innermost_casenull; + save_escontext = state->escontext; + + state->innermost_caseval = resv; + state->innermost_casenull = resnull; + state->escontext = escontext; + + ExecInitExprRec((Expr *) jsexpr->coercion_expr, state, resv, resnull); + + state->innermost_caseval = save_innermost_caseval; + state->innermost_casenull = save_innermost_casenull; + state->escontext = save_escontext; + } + else if (jsexpr->use_json_coercion) + { + jsestate->jump_eval_coercion = state->steps_len; + + ExecInitJsonCoercion(state, jsexpr->returning, escontext, resv, resnull); + } + else if (jsexpr->use_io_coercion) + { + /* + * Here we only need to initialize the FunctionCallInfo for the target + * type's input function, which is called by ExecEvalJsonExprPath() + * itself, so no additional step is necessary. + */ + Oid typinput; + Oid typioparam; + FmgrInfo *finfo; + FunctionCallInfo fcinfo; + + getTypeInputInfo(jsexpr->returning->typid, &typinput, &typioparam); + finfo = palloc0(sizeof(FmgrInfo)); + fcinfo = palloc0(SizeForFunctionCallInfo(3)); + fmgr_info(typinput, finfo); + fmgr_info_set_expr((Node *) jsexpr->returning, finfo); + InitFunctionCallInfoData(*fcinfo, finfo, 3, InvalidOid, NULL, NULL); + + /* + * We can preload the second and third arguments for the input + * function, since they're constants. + */ + fcinfo->args[1].value = ObjectIdGetDatum(typioparam); + fcinfo->args[1].isnull = false; + fcinfo->args[2].value = Int32GetDatum(jsexpr->returning->typmod); + fcinfo->args[2].isnull = false; + fcinfo->context = (Node *) escontext; + + jsestate->input_finfo = finfo; + jsestate->input_fcinfo = fcinfo; + } + + /* + * Add a special step, if needed, to check if the coercion evaluation ran + * into an error but was not thrown because the ON ERROR behavior is not + * ERROR. It will set jsesestate->error if an error did occur. + */ + if (jsestate->jump_eval_coercion >= 0 && escontext != NULL) + { + scratch->opcode = EEOP_JSONEXPR_COERCION_FINISH; + scratch->d.jsonexpr.jsestate = jsestate; + ExprEvalPushStep(state, scratch); + } + + jsestate->jump_empty = jsestate->jump_error = -1; + + /* + * Step to check jsestate->error and return the ON ERROR expression if + * there is one. This handles both the errors that occur during jsonpath + * evaluation in EEOP_JSONEXPR_PATH and subsequent coercion evaluation. + */ + if (jsexpr->on_error && + jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR) + { + jsestate->jump_error = state->steps_len; + + /* JUMP to end if false, that is, skip the ON ERROR expression. */ + jumps_to_end = lappend_int(jumps_to_end, state->steps_len); + scratch->opcode = EEOP_JUMP_IF_NOT_TRUE; + scratch->resvalue = &jsestate->error.value; + scratch->resnull = &jsestate->error.isnull; + scratch->d.jump.jumpdone = -1; /* set below */ + ExprEvalPushStep(state, scratch); + + /* Steps to evaluate the ON ERROR expression */ + ExecInitExprRec((Expr *) jsexpr->on_error->expr, + state, resv, resnull); + + /* Step to coerce the ON ERROR expression if needed */ + if (jsexpr->on_error->coerce) + ExecInitJsonCoercion(state, jsexpr->returning, escontext, resv, + resnull); + + /* JUMP to end to skip the ON EMPTY steps added below. */ + jumps_to_end = lappend_int(jumps_to_end, state->steps_len); + scratch->opcode = EEOP_JUMP; + scratch->d.jump.jumpdone = -1; + ExprEvalPushStep(state, scratch); + } + + /* + * Step to check jsestate->empty and return the ON EMPTY expression if + * there is one. + */ + if (jsexpr->on_empty != NULL && + jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR) + { + jsestate->jump_empty = state->steps_len; + + /* JUMP to end if false, that is, skip the ON EMPTY expression. */ + jumps_to_end = lappend_int(jumps_to_end, state->steps_len); + scratch->opcode = EEOP_JUMP_IF_NOT_TRUE; + scratch->resvalue = &jsestate->empty.value; + scratch->resnull = &jsestate->empty.isnull; + scratch->d.jump.jumpdone = -1; /* set below */ + ExprEvalPushStep(state, scratch); + + /* Steps to evaluate the ON EMPTY expression */ + ExecInitExprRec((Expr *) jsexpr->on_empty->expr, + state, resv, resnull); + + /* Step to coerce the ON EMPTY expression if needed */ + if (jsexpr->on_empty->coerce) + ExecInitJsonCoercion(state, jsexpr->returning, escontext, resv, + resnull); + } + + foreach(lc, jumps_to_end) + { + ExprEvalStep *as = &state->steps[lfirst_int(lc)]; + + as->d.jump.jumpdone = state->steps_len; + } + + jsestate->jump_end = state->steps_len; +} + +/* + * Initialize a EEOP_JSONEXPR_COERCION step to coerce the value given in resv + * to the given RETURNING type. + */ +static void +ExecInitJsonCoercion(ExprState *state, JsonReturning *returning, + ErrorSaveContext *escontext, + Datum *resv, bool *resnull) +{ + ExprEvalStep scratch = {0}; + + /* For json_populate_type() */ + scratch.opcode = EEOP_JSONEXPR_COERCION; + scratch.resvalue = resv; + scratch.resnull = resnull; + scratch.d.jsonexpr_coercion.targettype = returning->typid; + scratch.d.jsonexpr_coercion.targettypmod = returning->typmod; + scratch.d.jsonexpr_coercion.json_populate_type_cache = NULL; + scratch.d.jsonexpr_coercion.escontext = escontext; + ExprEvalPushStep(state, &scratch); +} diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c index a25ab7570f..24a3990a30 100644 --- a/src/backend/executor/execExprInterp.c +++ b/src/backend/executor/execExprInterp.c @@ -72,8 +72,8 @@ #include "utils/datum.h" #include "utils/expandedrecord.h" #include "utils/json.h" -#include "utils/jsonb.h" #include "utils/jsonfuncs.h" +#include "utils/jsonpath.h" #include "utils/lsyscache.h" #include "utils/memutils.h" #include "utils/timestamp.h" @@ -180,6 +180,7 @@ static pg_attribute_always_inline void ExecAggPlainTransByRef(AggState *aggstate AggStatePerGroup pergroup, ExprContext *aggcontext, int setno); +static char *ExecGetJsonValueItemString(JsonbValue *item, bool *resnull); /* * ScalarArrayOpExprHashEntry @@ -481,6 +482,9 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull) &&CASE_EEOP_XMLEXPR, &&CASE_EEOP_JSON_CONSTRUCTOR, &&CASE_EEOP_IS_JSON, + &&CASE_EEOP_JSONEXPR_PATH, + &&CASE_EEOP_JSONEXPR_COERCION, + &&CASE_EEOP_JSONEXPR_COERCION_FINISH, &&CASE_EEOP_AGGREF, &&CASE_EEOP_GROUPING_FUNC, &&CASE_EEOP_WINDOW_FUNC, @@ -1554,6 +1558,28 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull) EEO_NEXT(); } + EEO_CASE(EEOP_JSONEXPR_PATH) + { + /* too complex for an inline implementation */ + EEO_JUMP(ExecEvalJsonExprPath(state, op, econtext)); + } + + EEO_CASE(EEOP_JSONEXPR_COERCION) + { + /* too complex for an inline implementation */ + ExecEvalJsonCoercion(state, op, econtext); + + EEO_NEXT(); + } + + EEO_CASE(EEOP_JSONEXPR_COERCION_FINISH) + { + /* too complex for an inline implementation */ + ExecEvalJsonCoercionFinish(state, op); + + EEO_NEXT(); + } + EEO_CASE(EEOP_AGGREF) { /* @@ -4222,6 +4248,316 @@ ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op) *op->resvalue = BoolGetDatum(res); } +/* + * Evaluate a jsonpath against a document, both of which must have been + * evaluated and their values saved in op->d.jsonexpr.jsestate. + * + * If an error occurs during JsonPath* evaluation or when coercing its result + * to the RETURNING type, JsonExprState.error is set to true, provided the + * ON ERROR behavior is not ERROR. Similarly, if JsonPath{Query|Value}() found + * no matching items, JsonExprState.empty is set to true, provided the ON EMPTY + * behavior is not ERROR. That is to signal to the subsequent steps that check + * those flags to return the ON ERROR / ON EMPTY expression. + * + * Return value is the step address to be performed next. It will be one of + * jump_error, jump_empty, jump_eval_coercion, or jump_end, all given in + * op->d.jsonexpr.jsestate. + */ +int +ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op, + ExprContext *econtext) +{ + JsonExprState *jsestate = op->d.jsonexpr.jsestate; + JsonExpr *jsexpr = jsestate->jsexpr; + Datum item; + JsonPath *path; + bool throw_error = jsexpr->on_error->btype == JSON_BEHAVIOR_ERROR; + bool error = false, + empty = false; + int jump_eval_coercion = jsestate->jump_eval_coercion; + char *val_string = NULL; + + item = jsestate->formatted_expr.value; + path = DatumGetJsonPathP(jsestate->pathspec.value); + + /* Set error/empty to false. */ + memset(&jsestate->error, 0, sizeof(NullableDatum)); + memset(&jsestate->empty, 0, sizeof(NullableDatum)); + + /* + * Also reset ErrorSaveContext contents for the next row. Since we don't + * set details_wanted, we don't need to also reset error_data, which would + * be NULL anyway. + */ + Assert(!jsestate->escontext.details_wanted && + jsestate->escontext.error_data == NULL); + jsestate->escontext.error_occurred = false; + + switch (jsexpr->op) + { + case JSON_EXISTS_OP: + { + bool exists = JsonPathExists(item, path, + !throw_error ? &error : NULL, + jsestate->args); + + if (!error) + { + *op->resvalue = BoolGetDatum(exists); + *op->resnull = false; + } + } + break; + + case JSON_QUERY_OP: + *op->resvalue = JsonPathQuery(item, path, jsexpr->wrapper, &empty, + !throw_error ? &error : NULL, + jsestate->args); + + *op->resnull = (DatumGetPointer(*op->resvalue) == NULL); + + /* Handle OMIT QUOTES. */ + if (!*op->resnull && jsexpr->omit_quotes) + { + val_string = JsonbUnquote(DatumGetJsonbP(*op->resvalue)); + + /* + * Pass the string as a text value to the cast expression if + * one present. If not, use the input function call below to + * do the coercion. + */ + if (jump_eval_coercion >= 0) + *op->resvalue = + DirectFunctionCall1(textin, + PointerGetDatum(val_string)); + } + break; + + case JSON_VALUE_OP: + { + JsonbValue *jbv = JsonPathValue(item, path, &empty, + !throw_error ? &error : NULL, + jsestate->args); + + if (jbv == NULL) + { + /* Will be coerced with coercion_expr, if any. */ + *op->resvalue = (Datum) 0; + *op->resnull = true; + } + else if (!error && !empty) + { + if (jsexpr->returning->typid == JSONOID || + jsexpr->returning->typid == JSONBOID) + { + val_string = DatumGetCString(DirectFunctionCall1(jsonb_out, + JsonbPGetDatum(JsonbValueToJsonb(jbv)))); + } + else + { + val_string = ExecGetJsonValueItemString(jbv, op->resnull); + + /* + * Pass the string as a text value to the cast + * expression if one present. If not, use the input + * function call below to do the coercion. + */ + *op->resvalue = PointerGetDatum(val_string); + if (jump_eval_coercion >= 0) + *op->resvalue = DirectFunctionCall1(textin, *op->resvalue); + } + } + break; + } + + default: + elog(ERROR, "unrecognized SQL/JSON expression op %d", + (int) jsexpr->op); + return false; + } + + /* + * Coerce the result value to the RETURNING type by calling its input + * function. + */ + if (!*op->resnull && jsexpr->use_io_coercion) + { + FunctionCallInfo fcinfo; + + Assert(jump_eval_coercion == -1); + fcinfo = jsestate->input_fcinfo; + Assert(fcinfo != NULL); + Assert(val_string != NULL); + fcinfo->args[0].value = PointerGetDatum(val_string); + fcinfo->args[0].isnull = *op->resnull; + + /* + * Second and third arguments are already set up in + * ExecInitJsonExpr(). + */ + + fcinfo->isnull = false; + *op->resvalue = FunctionCallInvoke(fcinfo); + if (SOFT_ERROR_OCCURRED(&jsestate->escontext)) + error = true; + } + + /* Handle ON EMPTY. */ + if (empty) + { + if (jsexpr->on_empty) + { + if (jsexpr->on_empty->btype == JSON_BEHAVIOR_ERROR) + ereport(ERROR, + errcode(ERRCODE_NO_SQL_JSON_ITEM), + errmsg("no SQL/JSON item")); + else + jsestate->empty.value = BoolGetDatum(true); + + Assert(jsestate->jump_empty >= 0); + return jsestate->jump_empty; + } + else if (jsexpr->on_error->btype == JSON_BEHAVIOR_ERROR) + ereport(ERROR, + errcode(ERRCODE_NO_SQL_JSON_ITEM), + errmsg("no SQL/JSON item")); + else + jsestate->error.value = BoolGetDatum(true); + + *op->resvalue = (Datum) 0; + *op->resnull = true; + + Assert(!throw_error && jsestate->jump_error >= 0); + return jsestate->jump_error; + } + + /* + * ON ERROR. Wouldn't get here if the behavior is ERROR, because they + * would have already been thrown. + */ + if (error) + { + Assert(!throw_error && jsestate->jump_error >= 0); + *op->resvalue = (Datum) 0; + *op->resnull = true; + jsestate->error.value = BoolGetDatum(true); + return jsestate->jump_error; + } + + return jump_eval_coercion >= 0 ? jump_eval_coercion : jsestate->jump_end; +} + +/* + * Convert the given JsonbValue to its C string representation + * + * *resnull is set if the JsonbValue is a jbvNull. + */ +static char * +ExecGetJsonValueItemString(JsonbValue *item, bool *resnull) +{ + *resnull = false; + + /* get coercion state reference and datum of the corresponding SQL type */ + switch (item->type) + { + case jbvNull: + *resnull = true; + return NULL; + + case jbvString: + { + char *str = palloc(item->val.string.len + 1); + + memcpy(str, item->val.string.val, item->val.string.len); + str[item->val.string.len] = '\0'; + return str; + } + + case jbvNumeric: + return DatumGetCString(DirectFunctionCall1(numeric_out, + NumericGetDatum(item->val.numeric))); + + case jbvBool: + return DatumGetCString(DirectFunctionCall1(boolout, + BoolGetDatum(item->val.boolean))); + + case jbvDatetime: + switch (item->val.datetime.typid) + { + case DATEOID: + return DatumGetCString(DirectFunctionCall1(date_out, + item->val.datetime.value)); + case TIMEOID: + return DatumGetCString(DirectFunctionCall1(time_out, + item->val.datetime.value)); + case TIMETZOID: + return DatumGetCString(DirectFunctionCall1(timetz_out, + item->val.datetime.value)); + case TIMESTAMPOID: + return DatumGetCString(DirectFunctionCall1(timestamp_out, + item->val.datetime.value)); + case TIMESTAMPTZOID: + return DatumGetCString(DirectFunctionCall1(timestamptz_out, + item->val.datetime.value)); + default: + elog(ERROR, "unexpected jsonb datetime type oid %u", + item->val.datetime.typid); + } + break; + + case jbvArray: + case jbvObject: + case jbvBinary: + return DatumGetCString(DirectFunctionCall1(jsonb_out, + JsonbPGetDatum(JsonbValueToJsonb(item)))); + + default: + elog(ERROR, "unexpected jsonb value type %d", item->type); + } + + Assert(false); + *resnull = true; + return NULL; +} + +/* + * Coerce a jsonb value produced by ExecEvalJsonExprPath() or an ON ERROR / + * ON EMPTY behavior expression to the target type. + * + * Any soft errors that occur here will be checked by + * EEOP_JSONEXPR_COERCION_FINISH that will run after this. + */ +void +ExecEvalJsonCoercion(ExprState *state, ExprEvalStep *op, + ExprContext *econtext) +{ + ErrorSaveContext *escontext = op->d.jsonexpr_coercion.escontext; + + *op->resvalue = json_populate_type(*op->resvalue, JSONBOID, + op->d.jsonexpr_coercion.targettype, + op->d.jsonexpr_coercion.targettypmod, + &op->d.jsonexpr_coercion.json_populate_type_cache, + econtext->ecxt_per_query_memory, + op->resnull, (Node *) escontext); +} + +/* + * Checks if an error occurred either when evaluating JsonExpr.coercion_expr or + * in ExecEvalJsonCoercion(). If so, this sets JsonExprState.error to trigger + * the ON ERROR handling steps. + */ +void +ExecEvalJsonCoercionFinish(ExprState *state, ExprEvalStep *op) +{ + JsonExprState *jsestate = op->d.jsonexpr.jsestate; + + if (SOFT_ERROR_OCCURRED(&jsestate->escontext)) + { + *op->resvalue = (Datum) 0; + *op->resnull = true; + jsestate->error.value = BoolGetDatum(true); + } +} /* * ExecEvalGroupingFunc diff --git a/src/backend/jit/llvm/llvmjit_expr.c b/src/backend/jit/llvm/llvmjit_expr.c index 2a7d84f046..9e0efd2668 100644 --- a/src/backend/jit/llvm/llvmjit_expr.c +++ b/src/backend/jit/llvm/llvmjit_expr.c @@ -1930,6 +1930,114 @@ llvm_compile_expr(ExprState *state) LLVMBuildBr(b, opblocks[opno + 1]); break; + case EEOP_JSONEXPR_PATH: + { + JsonExprState *jsestate = op->d.jsonexpr.jsestate; + LLVMValueRef v_ret; + + /* + * Call ExecEvalJsonExprPath(). It returns the address of + * the step to perform next. + */ + v_ret = build_EvalXFunc(b, mod, "ExecEvalJsonExprPath", + v_state, op, v_econtext); + + /* + * Build a switch to map the return value (v_ret above), + * which is a runtime value of the step address to perform + * next, to either jump_empty, jump_error, + * jump_eval_coercion, or jump_end. + */ + if (jsestate->jump_empty >= 0 || + jsestate->jump_error >= 0 || + jsestate->jump_eval_coercion >= 0) + { + LLVMValueRef v_jump_empty; + LLVMValueRef v_jump_error; + LLVMValueRef v_jump_coercion; + LLVMValueRef v_switch; + LLVMBasicBlockRef b_done, + b_empty, + b_error, + b_coercion; + + b_empty = + l_bb_before_v(opblocks[opno + 1], + "op.%d.jsonexpr_empty", opno); + b_error = + l_bb_before_v(opblocks[opno + 1], + "op.%d.jsonexpr_error", opno); + b_coercion = + l_bb_before_v(opblocks[opno + 1], + "op.%d.jsonexpr_coercion", opno); + b_done = + l_bb_before_v(opblocks[opno + 1], + "op.%d.jsonexpr_done", opno); + + v_switch = LLVMBuildSwitch(b, + v_ret, + b_done, + 3); + /* Returned jsestate->jump_empty? */ + if (jsestate->jump_empty >= 0) + { + v_jump_empty = l_int32_const(lc, jsestate->jump_empty); + LLVMAddCase(v_switch, v_jump_empty, b_empty); + } + /* ON EMPTY code */ + LLVMPositionBuilderAtEnd(b, b_empty); + if (jsestate->jump_empty >= 0) + LLVMBuildBr(b, opblocks[jsestate->jump_empty]); + else + LLVMBuildUnreachable(b); + + /* Returned jsestate->jump_error? */ + if (jsestate->jump_error >= 0) + { + v_jump_error = l_int32_const(lc, jsestate->jump_error); + LLVMAddCase(v_switch, v_jump_error, b_error); + } + /* ON ERROR code */ + LLVMPositionBuilderAtEnd(b, b_error); + if (jsestate->jump_error >= 0) + LLVMBuildBr(b, opblocks[jsestate->jump_error]); + else + LLVMBuildUnreachable(b); + + /* Returned jsestate->jump_eval_coercion? */ + if (jsestate->jump_eval_coercion >= 0) + { + v_jump_coercion = l_int32_const(lc, jsestate->jump_eval_coercion); + LLVMAddCase(v_switch, v_jump_coercion, b_coercion); + } + /* coercion_expr code */ + LLVMPositionBuilderAtEnd(b, b_coercion); + if (jsestate->jump_eval_coercion >= 0) + LLVMBuildBr(b, opblocks[jsestate->jump_eval_coercion]); + else + LLVMBuildUnreachable(b); + + LLVMPositionBuilderAtEnd(b, b_done); + } + + LLVMBuildBr(b, opblocks[jsestate->jump_end]); + break; + } + + case EEOP_JSONEXPR_COERCION: + build_EvalXFunc(b, mod, "ExecEvalJsonCoercion", + v_state, op, v_econtext); + + LLVMBuildBr(b, opblocks[opno + 1]); + break; + + case EEOP_JSONEXPR_COERCION_FINISH: + build_EvalXFunc(b, mod, "ExecEvalJsonCoercionFinish", + v_state, op); + + LLVMBuildBr(b, opblocks[opno + 1]); + break; + case EEOP_AGGREF: { LLVMValueRef v_aggno; diff --git a/src/backend/jit/llvm/llvmjit_types.c b/src/backend/jit/llvm/llvmjit_types.c index 7d7aeee1f2..f93c383fd5 100644 --- a/src/backend/jit/llvm/llvmjit_types.c +++ b/src/backend/jit/llvm/llvmjit_types.c @@ -173,6 +173,9 @@ void *referenced_functions[] = ExecEvalXmlExpr, ExecEvalJsonConstructor, ExecEvalJsonIsPredicate, + ExecEvalJsonCoercion, + ExecEvalJsonCoercionFinish, + ExecEvalJsonExprPath, MakeExpandedObjectReadOnlyInternal, slot_getmissingattrs, slot_getsomeattrs_int, diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c index 33d4d23e23..b13cfa4201 100644 --- a/src/backend/nodes/makefuncs.c +++ b/src/backend/nodes/makefuncs.c @@ -856,6 +856,22 @@ makeJsonValueExpr(Expr *raw_expr, Expr *formatted_expr, return jve; } +/* + * makeJsonBehavior - + * creates a JsonBehavior node + */ +JsonBehavior * +makeJsonBehavior(JsonBehaviorType btype, Node *expr, int location) +{ + JsonBehavior *behavior = makeNode(JsonBehavior); + + behavior->btype = btype; + behavior->expr = expr; + behavior->location = location; + + return behavior; +} + /* * makeJsonKeyValue - * creates a JsonKeyValue node diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c index 5b702809ae..9f1553bccf 100644 --- a/src/backend/nodes/nodeFuncs.c +++ b/src/backend/nodes/nodeFuncs.c @@ -236,6 +236,20 @@ exprType(const Node *expr) case T_JsonIsPredicate: type = BOOLOID; break; + case T_JsonExpr: + { + const JsonExpr *jexpr = (const JsonExpr *) expr; + + type = jexpr->returning->typid; + break; + } + case T_JsonBehavior: + { + const JsonBehavior *behavior = (const JsonBehavior *) expr; + + type = exprType(behavior->expr); + break; + } case T_NullTest: type = BOOLOID; break; @@ -495,6 +509,20 @@ exprTypmod(const Node *expr) return exprTypmod((Node *) ((const JsonValueExpr *) expr)->formatted_expr); case T_JsonConstructorExpr: return ((const JsonConstructorExpr *) expr)->returning->typmod; + case T_JsonExpr: + { + const JsonExpr *jexpr = (const JsonExpr *) expr; + + return jexpr->returning->typmod; + } + break; + case T_JsonBehavior: + { + const JsonBehavior *behavior = (const JsonBehavior *) expr; + + return exprTypmod(behavior->expr); + } + break; case T_CoerceToDomain: return ((const CoerceToDomain *) expr)->resulttypmod; case T_CoerceToDomainValue: @@ -974,6 +1002,26 @@ exprCollation(const Node *expr) /* IS JSON's result is boolean ... */ coll = InvalidOid; /* ... so it has no collation */ break; + case T_JsonExpr: + { + const JsonExpr *jsexpr = (JsonExpr *) expr; + + if (jsexpr->coercion_expr) + coll = exprCollation(jsexpr->coercion_expr); + else + coll = jsexpr->collation; + } + break; + case T_JsonBehavior: + { + const JsonBehavior *behavior = (JsonBehavior *) expr; + + if (behavior->expr) + coll = exprCollation(behavior->expr); + else + coll = InvalidOid; + } + break; case T_NullTest: /* NullTest's result is boolean ... */ coll = InvalidOid; /* ... so it has no collation */ @@ -1213,6 +1261,24 @@ exprSetCollation(Node *expr, Oid collation) case T_JsonIsPredicate: Assert(!OidIsValid(collation)); /* result is always boolean */ break; + case T_JsonExpr: + { + JsonExpr *jexpr = (JsonExpr *) expr; + + if (jexpr->coercion_expr) + exprSetCollation((Node *) jexpr->coercion_expr, collation); + else + jexpr->collation = collation; + } + break; + case T_JsonBehavior: + { + JsonBehavior *behavior = (JsonBehavior *) expr; + + if (behavior->expr) + exprSetCollation(behavior->expr, collation); + } + break; case T_NullTest: /* NullTest's result is boolean ... */ Assert(!OidIsValid(collation)); /* ... so never set a collation */ @@ -1519,6 +1585,18 @@ exprLocation(const Node *expr) case T_JsonIsPredicate: loc = ((const JsonIsPredicate *) expr)->location; break; + case T_JsonExpr: + { + const JsonExpr *jsexpr = (const JsonExpr *) expr; + + /* consider both function name and leftmost arg */ + loc = leftmostLoc(jsexpr->location, + exprLocation(jsexpr->formatted_expr)); + } + break; + case T_JsonBehavior: + loc = exprLocation(((JsonBehavior *) expr)->expr); + break; case T_NullTest: { const NullTest *nexpr = (const NullTest *) expr; @@ -2272,6 +2350,33 @@ expression_tree_walker_impl(Node *node, break; case T_JsonIsPredicate: return WALK(((JsonIsPredicate *) node)->expr); + case T_JsonExpr: + { + JsonExpr *jexpr = (JsonExpr *) node; + + if (WALK(jexpr->formatted_expr)) + return true; + if (WALK(jexpr->path_spec)) + return true; + if (WALK(jexpr->coercion_expr)) + return true; + if (WALK(jexpr->passing_values)) + return true; + /* we assume walker doesn't care about passing_names */ + if (WALK(jexpr->on_empty)) + return true; + if (WALK(jexpr->on_error)) + return true; + } + break; + case T_JsonBehavior: + { + JsonBehavior *behavior = (JsonBehavior *) node; + + if (WALK(behavior->expr)) + return true; + } + break; case T_NullTest: return WALK(((NullTest *) node)->arg); case T_BooleanTest: @@ -3276,6 +3381,32 @@ expression_tree_mutator_impl(Node *node, return (Node *) newnode; } + case T_JsonExpr: + { + JsonExpr *jexpr = (JsonExpr *) node; + JsonExpr *newnode; + + FLATCOPY(newnode, jexpr, JsonExpr); + MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *); + MUTATE(newnode->path_spec, jexpr->path_spec, Node *); + MUTATE(newnode->coercion_expr, jexpr->coercion_expr, Node *); + MUTATE(newnode->passing_values, jexpr->passing_values, List *); + /* assume mutator does not care about passing_names */ + MUTATE(newnode->on_empty, jexpr->on_empty, JsonBehavior *); + MUTATE(newnode->on_error, jexpr->on_error, JsonBehavior *); + return (Node *) newnode; + } + break; + case T_JsonBehavior: + { + JsonBehavior *behavior = (JsonBehavior *) node; + JsonBehavior *newnode; + + FLATCOPY(newnode, behavior, JsonBehavior); + MUTATE(newnode->expr, behavior->expr, Node *); + return (Node *) newnode; + } + break; case T_NullTest: { NullTest *ntest = (NullTest *) node; @@ -3965,6 +4096,34 @@ raw_expression_tree_walker_impl(Node *node, break; case T_JsonIsPredicate: return WALK(((JsonIsPredicate *) node)->expr); + case T_JsonArgument: + return WALK(((JsonArgument *) node)->val); + case T_JsonFuncExpr: + { + JsonFuncExpr *jfe = (JsonFuncExpr *) node; + + if (WALK(jfe->context_item)) + return true; + if (WALK(jfe->pathspec)) + return true; + if (WALK(jfe->passing)) + return true; + if (WALK(jfe->output)) + return true; + if (WALK(jfe->on_empty)) + return true; + if (WALK(jfe->on_error)) + return true; + } + break; + case T_JsonBehavior: + { + JsonBehavior *jb = (JsonBehavior *) node; + + if (WALK(jb->expr)) + return true; + } + break; case T_NullTest: return WALK(((NullTest *) node)->arg); case T_BooleanTest: diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c index 83a0aed051..3c14c605a0 100644 --- a/src/backend/optimizer/path/costsize.c +++ b/src/backend/optimizer/path/costsize.c @@ -4878,7 +4878,8 @@ cost_qual_eval_walker(Node *node, cost_qual_eval_context *context) IsA(node, SQLValueFunction) || IsA(node, XmlExpr) || IsA(node, CoerceToDomain) || - IsA(node, NextValueExpr)) + IsA(node, NextValueExpr) || + IsA(node, JsonExpr)) { /* Treat all these as having cost 1 */ context->total.per_tuple += cpu_operator_cost; diff --git a/src/backend/optimizer/util/clauses.c b/src/backend/optimizer/util/clauses.c index d09dde210f..b50fe58d1c 100644 --- a/src/backend/optimizer/util/clauses.c +++ b/src/backend/optimizer/util/clauses.c @@ -50,6 +50,7 @@ #include "utils/fmgroids.h" #include "utils/json.h" #include "utils/jsonb.h" +#include "utils/jsonpath.h" #include "utils/lsyscache.h" #include "utils/memutils.h" #include "utils/syscache.h" @@ -414,6 +415,25 @@ contain_mutable_functions_walker(Node *node, void *context) /* Check all subnodes */ } + if (IsA(node, JsonExpr)) + { + JsonExpr *jexpr = castNode(JsonExpr, node); + Const *cnst; + + if (!IsA(jexpr->path_spec, Const)) + return true; + + cnst = castNode(Const, jexpr->path_spec); + + Assert(cnst->consttype == JSONPATHOID); + if (cnst->constisnull) + return false; + + if (jspIsMutable(DatumGetJsonPathP(cnst->constvalue), + jexpr->passing_names, jexpr->passing_values)) + return true; + } + if (IsA(node, SQLValueFunction)) { /* all variants of SQLValueFunction are stable */ diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index 39a801a1c3..c247eefb0c 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -653,10 +653,19 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); json_returning_clause_opt json_name_and_value json_aggregate_func + json_argument + json_behavior + json_on_error_clause_opt %type json_name_and_value_list json_value_expr_list json_array_aggregate_order_by_clause_opt -%type json_predicate_type_constraint + json_arguments + json_behavior_clause_opt + json_passing_clause_opt +%type json_behavior_type + json_predicate_type_constraint + json_quotes_clause_opt + json_wrapper_behavior %type json_key_uniqueness_constraint_opt json_object_constructor_null_clause_opt json_array_constructor_null_clause_opt @@ -697,7 +706,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); CACHE CALL CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P CHARACTER CHARACTERISTICS CHECK CHECKPOINT CLASS CLOSE CLUSTER COALESCE COLLATE COLLATION COLUMN COLUMNS COMMENT COMMENTS COMMIT - COMMITTED COMPRESSION CONCURRENTLY CONFIGURATION CONFLICT + COMMITTED COMPRESSION CONCURRENTLY CONDITIONAL CONFIGURATION CONFLICT CONNECTION CONSTRAINT CONSTRAINTS CONTENT_P CONTINUE_P CONVERSION_P COPY COST CREATE CROSS CSV CUBE CURRENT_P CURRENT_CATALOG CURRENT_DATE CURRENT_ROLE CURRENT_SCHEMA @@ -708,8 +717,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); DETACH DICTIONARY DISABLE_P DISCARD DISTINCT DO DOCUMENT_P DOMAIN_P DOUBLE_P DROP - EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EVENT EXCEPT - EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION + EACH ELSE EMPTY_P ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ERROR_P ESCAPE + EVENT EXCEPT EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION EXTENSION EXTERNAL EXTRACT FALSE_P FAMILY FETCH FILTER FINALIZE FIRST_P FLOAT_P FOLLOWING FOR @@ -724,10 +733,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION - JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_OBJECT JSON_OBJECTAGG - JSON_SCALAR JSON_SERIALIZE + JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG + JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE - KEY KEYS + KEEP KEY KEYS LABEL LANGUAGE LARGE_P LAST_P LATERAL_P LEADING LEAKPROOF LEAST LEFT LEVEL LIKE LIMIT LISTEN LOAD LOCAL @@ -741,7 +750,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF NULLS_P NUMERIC - OBJECT_P OF OFF OFFSET OIDS OLD ON ONLY OPERATOR OPTION OPTIONS OR + OBJECT_P OF OFF OFFSET OIDS OLD OMIT ON ONLY OPERATOR OPTION OPTIONS OR ORDER ORDINALITY OTHERS OUT_P OUTER_P OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER @@ -750,7 +759,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION - QUOTE + QUOTE QUOTES RANGE READ REAL REASSIGN RECHECK RECURSIVE REF_P REFERENCES REFERENCING REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA @@ -761,7 +770,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P - START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P + START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER TABLE TABLES TABLESAMPLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN @@ -769,7 +778,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); TREAT TRIGGER TRIM TRUE_P TRUNCATE TRUSTED TYPE_P TYPES_P - UESCAPE UNBOUNDED UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN + UESCAPE UNBOUNDED UNCONDITIONAL UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN UNLISTEN UNLOGGED UNTIL UPDATE USER USING VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING @@ -15805,6 +15814,62 @@ func_expr_common_subexpr: m->location = @1; $$ = (Node *) m; } + | JSON_QUERY '(' + json_value_expr ',' a_expr json_passing_clause_opt + json_returning_clause_opt + json_wrapper_behavior + json_quotes_clause_opt + json_behavior_clause_opt + ')' + { + JsonFuncExpr *n = makeNode(JsonFuncExpr); + + n->op = JSON_QUERY_OP; + n->context_item = (JsonValueExpr *) $3; + n->pathspec = $5; + n->passing = $6; + n->output = (JsonOutput *) $7; + n->wrapper = $8; + n->quotes = $9; + n->on_empty = (JsonBehavior *) linitial($10); + n->on_error = (JsonBehavior *) lsecond($10); + n->location = @1; + $$ = (Node *) n; + } + | JSON_EXISTS '(' + json_value_expr ',' a_expr json_passing_clause_opt + json_on_error_clause_opt + ')' + { + JsonFuncExpr *n = makeNode(JsonFuncExpr); + + n->op = JSON_EXISTS_OP; + n->context_item = (JsonValueExpr *) $3; + n->pathspec = $5; + n->passing = $6; + n->output = NULL; + n->on_error = (JsonBehavior *) $7; + n->location = @1; + $$ = (Node *) n; + } + | JSON_VALUE '(' + json_value_expr ',' a_expr json_passing_clause_opt + json_returning_clause_opt + json_behavior_clause_opt + ')' + { + JsonFuncExpr *n = makeNode(JsonFuncExpr); + + n->op = JSON_VALUE_OP; + n->context_item = (JsonValueExpr *) $3; + n->pathspec = $5; + n->passing = $6; + n->output = (JsonOutput *) $7; + n->on_empty = (JsonBehavior *) linitial($8); + n->on_error = (JsonBehavior *) lsecond($8); + n->location = @1; + $$ = (Node *) n; + } ; @@ -16531,6 +16596,77 @@ opt_asymmetric: ASYMMETRIC ; /* SQL/JSON support */ +json_passing_clause_opt: + PASSING json_arguments { $$ = $2; } + | /*EMPTY*/ { $$ = NIL; } + ; + +json_arguments: + json_argument { $$ = list_make1($1); } + | json_arguments ',' json_argument { $$ = lappend($1, $3); } + ; + +json_argument: + json_value_expr AS ColLabel + { + JsonArgument *n = makeNode(JsonArgument); + + n->val = (JsonValueExpr *) $1; + n->name = $3; + $$ = (Node *) n; + } + ; + +/* ARRAY is a noise word */ +json_wrapper_behavior: + WITHOUT WRAPPER { $$ = JSW_NONE; } + | WITHOUT ARRAY WRAPPER { $$ = JSW_NONE; } + | WITH WRAPPER { $$ = JSW_UNCONDITIONAL; } + | WITH ARRAY WRAPPER { $$ = JSW_UNCONDITIONAL; } + | WITH CONDITIONAL ARRAY WRAPPER { $$ = JSW_CONDITIONAL; } + | WITH UNCONDITIONAL ARRAY WRAPPER { $$ = JSW_UNCONDITIONAL; } + | WITH CONDITIONAL WRAPPER { $$ = JSW_CONDITIONAL; } + | WITH UNCONDITIONAL WRAPPER { $$ = JSW_UNCONDITIONAL; } + | /* empty */ { $$ = JSW_UNSPEC; } + ; + +json_behavior: + DEFAULT a_expr + { $$ = (Node *) makeJsonBehavior(JSON_BEHAVIOR_DEFAULT, $2, @1); } + | json_behavior_type + { $$ = (Node *) makeJsonBehavior($1, NULL, @1); } + ; + +json_behavior_type: + ERROR_P { $$ = JSON_BEHAVIOR_ERROR; } + | NULL_P { $$ = JSON_BEHAVIOR_NULL; } + | TRUE_P { $$ = JSON_BEHAVIOR_TRUE; } + | FALSE_P { $$ = JSON_BEHAVIOR_FALSE; } + | UNKNOWN { $$ = JSON_BEHAVIOR_UNKNOWN; } + | EMPTY_P ARRAY { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; } + | EMPTY_P OBJECT_P { $$ = JSON_BEHAVIOR_EMPTY_OBJECT; } + /* non-standard, for Oracle compatibility only */ + | EMPTY_P { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; } + ; + +json_behavior_clause_opt: + json_behavior ON EMPTY_P + { $$ = list_make2($1, NULL); } + | json_behavior ON ERROR_P + { $$ = list_make2(NULL, $1); } + | json_behavior ON EMPTY_P json_behavior ON ERROR_P + { $$ = list_make2($1, $4); } + | /* EMPTY */ + { $$ = list_make2(NULL, NULL); } + ; + +json_on_error_clause_opt: + json_behavior ON ERROR_P + { $$ = $1; } + | /* EMPTY */ + { $$ = NULL; } + ; + json_value_expr: a_expr json_format_clause_opt { @@ -16575,6 +16711,14 @@ json_format_clause_opt: } ; +json_quotes_clause_opt: + KEEP QUOTES ON SCALAR STRING_P { $$ = JS_QUOTES_KEEP; } + | KEEP QUOTES { $$ = JS_QUOTES_KEEP; } + | OMIT QUOTES ON SCALAR STRING_P { $$ = JS_QUOTES_OMIT; } + | OMIT QUOTES { $$ = JS_QUOTES_OMIT; } + | /* EMPTY */ { $$ = JS_QUOTES_UNSPEC; } + ; + json_returning_clause_opt: RETURNING Typename json_format_clause_opt { @@ -17191,6 +17335,7 @@ unreserved_keyword: | COMMIT | COMMITTED | COMPRESSION + | CONDITIONAL | CONFIGURATION | CONFLICT | CONNECTION @@ -17227,10 +17372,12 @@ unreserved_keyword: | DOUBLE_P | DROP | EACH + | EMPTY_P | ENABLE_P | ENCODING | ENCRYPTED | ENUM_P + | ERROR_P | ESCAPE | EVENT | EXCLUDE @@ -17280,6 +17427,7 @@ unreserved_keyword: | INSTEAD | INVOKER | ISOLATION + | KEEP | KEY | KEYS | LABEL @@ -17326,6 +17474,7 @@ unreserved_keyword: | OFF | OIDS | OLD + | OMIT | OPERATOR | OPTION | OPTIONS @@ -17356,6 +17505,7 @@ unreserved_keyword: | PROGRAM | PUBLICATION | QUOTE + | QUOTES | RANGE | READ | REASSIGN @@ -17415,6 +17565,7 @@ unreserved_keyword: | STORAGE | STORED | STRICT_P + | STRING_P | STRIP_P | SUBSCRIPTION | SUPPORT @@ -17437,6 +17588,7 @@ unreserved_keyword: | UESCAPE | UNBOUNDED | UNCOMMITTED + | UNCONDITIONAL | UNENCRYPTED | UNKNOWN | UNLISTEN @@ -17497,10 +17649,13 @@ col_name_keyword: | JSON | JSON_ARRAY | JSON_ARRAYAGG + | JSON_EXISTS | JSON_OBJECT | JSON_OBJECTAGG + | JSON_QUERY | JSON_SCALAR | JSON_SERIALIZE + | JSON_VALUE | LEAST | MERGE_ACTION | NATIONAL @@ -17734,6 +17889,7 @@ bare_label_keyword: | COMMITTED | COMPRESSION | CONCURRENTLY + | CONDITIONAL | CONFIGURATION | CONFLICT | CONNECTION @@ -17786,11 +17942,13 @@ bare_label_keyword: | DROP | EACH | ELSE + | EMPTY_P | ENABLE_P | ENCODING | ENCRYPTED | END_P | ENUM_P + | ERROR_P | ESCAPE | EVENT | EXCLUDE @@ -17860,10 +18018,14 @@ bare_label_keyword: | JSON | JSON_ARRAY | JSON_ARRAYAGG + | JSON_EXISTS | JSON_OBJECT | JSON_OBJECTAGG + | JSON_QUERY | JSON_SCALAR | JSON_SERIALIZE + | JSON_VALUE + | KEEP | KEY | KEYS | LABEL @@ -17925,6 +18087,7 @@ bare_label_keyword: | OFF | OIDS | OLD + | OMIT | ONLY | OPERATOR | OPTION @@ -17962,6 +18125,7 @@ bare_label_keyword: | PROGRAM | PUBLICATION | QUOTE + | QUOTES | RANGE | READ | REAL @@ -18030,6 +18194,7 @@ bare_label_keyword: | STORAGE | STORED | STRICT_P + | STRING_P | STRIP_P | SUBSCRIPTION | SUBSTRING @@ -18064,6 +18229,7 @@ bare_label_keyword: | UESCAPE | UNBOUNDED | UNCOMMITTED + | UNCONDITIONAL | UNENCRYPTED | UNIQUE | UNKNOWN diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c index d44b1f2ab2..7166138bf7 100644 --- a/src/backend/parser/parse_expr.c +++ b/src/backend/parser/parse_expr.c @@ -37,6 +37,7 @@ #include "utils/builtins.h" #include "utils/date.h" #include "utils/fmgroids.h" +#include "utils/jsonb.h" #include "utils/lsyscache.h" #include "utils/timestamp.h" #include "utils/xml.h" @@ -91,6 +92,15 @@ static Node *transformJsonParseExpr(ParseState *pstate, JsonParseExpr *expr); static Node *transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *expr); static Node *transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr); +static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *p); +static void transformJsonPassingArgs(ParseState *pstate, const char *constructName, + JsonFormatType format, List *args, + List **passing_values, List **passing_names); +static void coerceJsonExprOutput(ParseState *pstate, JsonExpr *jsexpr); +static JsonBehavior *transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior, + JsonBehaviorType default_behavior, + JsonReturning *returning); +static Node *GetJsonBehaviorConst(JsonBehaviorType btype, int location); static Node *make_row_comparison_op(ParseState *pstate, List *opname, List *largs, List *rargs, int location); static Node *make_row_distinct_op(ParseState *pstate, List *opname, @@ -359,6 +369,10 @@ transformExprRecurse(ParseState *pstate, Node *expr) result = transformJsonSerializeExpr(pstate, (JsonSerializeExpr *) expr); break; + case T_JsonFuncExpr: + result = transformJsonFuncExpr(pstate, (JsonFuncExpr *) expr); + break; + default: /* should not reach here */ elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr)); @@ -3263,7 +3277,7 @@ makeJsonByteaToTextConversion(Node *expr, JsonFormat *format, int location) static Node * transformJsonValueExpr(ParseState *pstate, const char *constructName, JsonValueExpr *ve, JsonFormatType default_format, - Oid targettype) + Oid targettype, bool isarg) { Node *expr = transformExprRecurse(pstate, (Node *) ve->raw_expr); Node *rawexpr; @@ -3295,6 +3309,41 @@ transformJsonValueExpr(ParseState *pstate, const char *constructName, else format = ve->format->format_type; } + else if (isarg) + { + /* + * Special treatment for PASSING arguments. + * + * Pass types supported by GetJsonPathVar() / JsonItemFromDatum() + * directly without converting to json[b]. + */ + switch (exprtype) + { + case BOOLOID: + case NUMERICOID: + case INT2OID: + case INT4OID: + case INT8OID: + case FLOAT4OID: + case FLOAT8OID: + case TEXTOID: + case VARCHAROID: + case DATEOID: + case TIMEOID: + case TIMETZOID: + case TIMESTAMPOID: + case TIMESTAMPTZOID: + return expr; + + default: + if (typcategory == TYPCATEGORY_STRING) + return expr; + /* else convert argument to json[b] type */ + break; + } + + format = default_format; + } else if (exprtype == JSONOID || exprtype == JSONBOID) format = JS_FORMAT_DEFAULT; /* do not format json[b] types */ else @@ -3306,7 +3355,12 @@ transformJsonValueExpr(ParseState *pstate, const char *constructName, Node *coerced; bool only_allow_cast = OidIsValid(targettype); - if (!only_allow_cast && + /* + * PASSING args are handled appropriately by GetJsonPathVar() / + * JsonItemFromDatum(). + */ + if (!isarg && + !only_allow_cast && exprtype != BYTEAOID && typcategory != TYPCATEGORY_STRING) ereport(ERROR, errcode(ERRCODE_DATATYPE_MISMATCH), @@ -3459,6 +3513,11 @@ transformJsonOutput(ParseState *pstate, const JsonOutput *output, errcode(ERRCODE_FEATURE_NOT_SUPPORTED), errmsg("returning SETOF types is not supported in SQL/JSON functions")); + if (get_typtype(ret->typid) == TYPTYPE_PSEUDO) + ereport(ERROR, + errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("returning pseudo-types is not supported in SQL/JSON functions")); + if (ret->format->format_type == JS_FORMAT_DEFAULT) /* assign JSONB format when returning jsonb, or JSON format otherwise */ ret->format->format_type = @@ -3555,7 +3614,6 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr, /* try to coerce expression to the output type */ res = coerce_to_target_type(pstate, expr, exprtype, returning->typid, returning->typmod, - /* XXX throwing errors when casting to char(N) */ COERCION_EXPLICIT, COERCE_EXPLICIT_CAST, location); @@ -3655,7 +3713,7 @@ transformJsonObjectConstructor(ParseState *pstate, JsonObjectConstructor *ctor) Node *val = transformJsonValueExpr(pstate, "JSON_OBJECT()", kv->value, JS_FORMAT_DEFAULT, - InvalidOid); + InvalidOid, false); args = lappend(args, key); args = lappend(args, val); @@ -3842,7 +3900,7 @@ transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg) val = transformJsonValueExpr(pstate, "JSON_OBJECTAGG()", agg->arg->value, JS_FORMAT_DEFAULT, - InvalidOid); + InvalidOid, false); args = list_make2(key, val); returning = transformJsonConstructorOutput(pstate, agg->constructor->output, @@ -3898,9 +3956,8 @@ transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg) Oid aggfnoid; Oid aggtype; - arg = transformJsonValueExpr(pstate, "JSON_ARRAYAGG()", - agg->arg, - JS_FORMAT_DEFAULT, InvalidOid); + arg = transformJsonValueExpr(pstate, "JSON_ARRAYAGG()", agg->arg, + JS_FORMAT_DEFAULT, InvalidOid, false); returning = transformJsonConstructorOutput(pstate, agg->constructor->output, list_make1(arg)); @@ -3947,9 +4004,8 @@ transformJsonArrayConstructor(ParseState *pstate, JsonArrayConstructor *ctor) { JsonValueExpr *jsval = castNode(JsonValueExpr, lfirst(lc)); Node *val = transformJsonValueExpr(pstate, "JSON_ARRAY()", - jsval, - JS_FORMAT_DEFAULT, - InvalidOid); + jsval, JS_FORMAT_DEFAULT, + InvalidOid, false); args = lappend(args, val); } @@ -4108,7 +4164,7 @@ transformJsonParseExpr(ParseState *pstate, JsonParseExpr *jsexpr) * function-like CASTs. */ arg = transformJsonValueExpr(pstate, "JSON()", jsexpr->expr, - JS_FORMAT_JSON, returning->typid); + JS_FORMAT_JSON, returning->typid, false); } return makeJsonConstructorExpr(pstate, JSCTOR_JSON_PARSE, list_make1(arg), NULL, @@ -4153,7 +4209,7 @@ transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr) Node *arg = transformJsonValueExpr(pstate, "JSON_SERIALIZE()", expr->expr, JS_FORMAT_JSON, - InvalidOid); + InvalidOid, false); if (expr->output) { @@ -4187,3 +4243,474 @@ transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr) return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SERIALIZE, list_make1(arg), NULL, returning, false, false, expr->location); } + +/* + * Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS functions into a JsonExpr node. + */ +static Node * +transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func) +{ + JsonExpr *jsexpr; + Node *path_spec; + const char *func_name = NULL; + JsonFormatType default_format; + + switch (func->op) + { + case JSON_EXISTS_OP: + func_name = "JSON_EXISTS"; + default_format = JS_FORMAT_DEFAULT; + break; + case JSON_QUERY_OP: + func_name = "JSON_QUERY"; + default_format = JS_FORMAT_JSONB; + break; + case JSON_VALUE_OP: + func_name = "JSON_VALUE"; + default_format = JS_FORMAT_DEFAULT; + break; + default: + elog(ERROR, "invalid JsonFuncExpr op %d", (int) func->op); + break; + } + + /* + * Even though the syntax allows it, FORMAT JSON specification in + * RETURNING is meaningless except for JSON_QUERY(). Flag if not + * JSON_QUERY(). + */ + if (func->output && func->op != JSON_QUERY_OP) + { + JsonFormat *format = func->output->returning->format; + + if (format->format_type != JS_FORMAT_DEFAULT || + format->encoding != JS_ENC_DEFAULT) + ereport(ERROR, + errcode(ERRCODE_SYNTAX_ERROR), + errmsg("cannot specify FORMAT JSON in RETURNING clause of %s()", + func_name), + parser_errposition(pstate, format->location)); + } + + /* OMIT QUOTES is meaningless when strings are wrapped. */ + if (func->op == JSON_QUERY_OP && + func->quotes != JS_QUOTES_UNSPEC && + (func->wrapper == JSW_CONDITIONAL || + func->wrapper == JSW_UNCONDITIONAL)) + ereport(ERROR, + errcode(ERRCODE_SYNTAX_ERROR), + errmsg("SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used"), + parser_errposition(pstate, func->location)); + + jsexpr = makeNode(JsonExpr); + jsexpr->location = func->location; + jsexpr->op = func->op; + + /* + * jsonpath machinery can only handle jsonb documents, so coerce the input + * if not already of jsonb type. + */ + jsexpr->formatted_expr = transformJsonValueExpr(pstate, func_name, + func->context_item, + default_format, + JSONBOID, + false); + jsexpr->format = func->context_item->format; + + path_spec = transformExprRecurse(pstate, func->pathspec); + path_spec = coerce_to_target_type(pstate, path_spec, exprType(path_spec), + JSONPATHOID, -1, + COERCION_EXPLICIT, COERCE_IMPLICIT_CAST, + exprLocation(path_spec)); + if (path_spec == NULL) + ereport(ERROR, + (errcode(ERRCODE_DATATYPE_MISMATCH), + errmsg("JSON path expression must be of type %s, not of type %s", + "jsonpath", format_type_be(exprType(path_spec))), + parser_errposition(pstate, exprLocation(path_spec)))); + jsexpr->path_spec = path_spec; + + /* Transform and coerce the PASSING arguments to to jsonb. */ + transformJsonPassingArgs(pstate, func_name, + JS_FORMAT_JSONB, + func->passing, + &jsexpr->passing_values, + &jsexpr->passing_names); + + /* Transform the JsonOutput into JsonReturning. */ + jsexpr->returning = transformJsonOutput(pstate, func->output, false); + + switch (func->op) + { + case JSON_EXISTS_OP: + /* JSON_EXISTS returns boolean by default. */ + if (!OidIsValid(jsexpr->returning->typid)) + { + jsexpr->returning->typid = BOOLOID; + jsexpr->returning->typmod = -1; + } + + jsexpr->on_error = transformJsonBehavior(pstate, func->on_error, + JSON_BEHAVIOR_FALSE, + jsexpr->returning); + break; + + case JSON_QUERY_OP: + /* JSON_QUERY returns jsonb by default. */ + if (!OidIsValid(jsexpr->returning->typid)) + { + JsonReturning *ret = jsexpr->returning; + + ret->typid = JSONBOID; + ret->typmod = -1; + } + + /* + * Keep quotes on scalar strings by default, omitting them only if + * OMIT QUOTES is specified. + */ + jsexpr->omit_quotes = (func->quotes == JS_QUOTES_OMIT); + jsexpr->wrapper = func->wrapper; + + coerceJsonExprOutput(pstate, jsexpr); + + if (func->on_empty) + jsexpr->on_empty = transformJsonBehavior(pstate, + func->on_empty, + JSON_BEHAVIOR_NULL, + jsexpr->returning); + jsexpr->on_error = transformJsonBehavior(pstate, func->on_error, + JSON_BEHAVIOR_NULL, + jsexpr->returning); + break; + + case JSON_VALUE_OP: + /* JSON_VALUE returns text by default. */ + if (!OidIsValid(jsexpr->returning->typid)) + { + jsexpr->returning->typid = TEXTOID; + jsexpr->returning->typmod = -1; + } + + /* + * Override whatever transformJsonOutput() set these to, which + * assumes that output type to be jsonb. + */ + jsexpr->returning->format->format_type = JS_FORMAT_DEFAULT; + jsexpr->returning->format->encoding = JS_ENC_DEFAULT; + + /* Always omit quotes from scalar strings. */ + jsexpr->omit_quotes = true; + + coerceJsonExprOutput(pstate, jsexpr); + + if (func->on_empty) + jsexpr->on_empty = transformJsonBehavior(pstate, + func->on_empty, + JSON_BEHAVIOR_NULL, + jsexpr->returning); + jsexpr->on_error = transformJsonBehavior(pstate, func->on_error, + JSON_BEHAVIOR_NULL, + jsexpr->returning); + break; + + default: + elog(ERROR, "invalid JsonFuncExpr op %d", (int) func->op); + break; + } + + return (Node *) jsexpr; +} + +/* + * Transform a SQL/JSON PASSING clause. + */ +static void +transformJsonPassingArgs(ParseState *pstate, const char *constructName, + JsonFormatType format, List *args, + List **passing_values, List **passing_names) +{ + ListCell *lc; + + *passing_values = NIL; + *passing_names = NIL; + + foreach(lc, args) + { + JsonArgument *arg = castNode(JsonArgument, lfirst(lc)); + Node *expr = transformJsonValueExpr(pstate, constructName, + arg->val, format, + InvalidOid, true); + + *passing_values = lappend(*passing_values, expr); + *passing_names = lappend(*passing_names, makeString(arg->name)); + } +} + +/* + * Set up to coerce the result value of JSON_VALUE() / JSON_QUERY() to the + * RETURNING type (default or user-specified), if needed. + */ +static void +coerceJsonExprOutput(ParseState *pstate, JsonExpr *jsexpr) +{ + JsonReturning *returning = jsexpr->returning; + Node *context_item = jsexpr->formatted_expr; + int default_typmod; + Oid default_typid; + bool omit_quotes = + jsexpr->op == JSON_QUERY_OP && jsexpr->omit_quotes; + Node *coercion_expr = NULL; + + Assert(returning); + + /* + * Check for cases where the coercion should be handled at runtime, that + * is, without using a cast expression. + */ + if (jsexpr->op == JSON_VALUE_OP) + { + /* + * Use cast expressions for types with typmod and domain types. + */ + if (returning->typmod == -1 && + get_typtype(returning->typid) != TYPTYPE_DOMAIN) + { + jsexpr->use_io_coercion = true; + return; + } + } + else if (jsexpr->op == JSON_QUERY_OP) + { + /* + * Cast functions from jsonb to the following types (jsonb_bool() et + * al) don't handle errors softly, so coerce either by calling + * json_populate_type() or the type's input function so that any + * errors are handled appropriately. The latter only if OMIT QUOTES is + * true. + */ + switch (returning->typid) + { + case BOOLOID: + case NUMERICOID: + case INT2OID: + case INT4OID: + case INT8OID: + case FLOAT4OID: + case FLOAT8OID: + if (jsexpr->omit_quotes) + jsexpr->use_io_coercion = true; + else + jsexpr->use_json_coercion = true; + return; + default: + break; + } + } + + /* Look up a cast expression. */ + + /* + * For JSON_VALUE() and for JSON_QUERY() when OMIT QUOTES is true, + * ExecEvalJsonExprPath() will convert a quote-stripped source value to + * its text representation, so use TEXTOID as the source type. + */ + if (omit_quotes || jsexpr->op == JSON_VALUE_OP) + { + default_typid = TEXTOID; + default_typmod = -1; + } + else + { + default_typid = exprType(context_item); + default_typmod = exprTypmod(context_item); + } + + if (returning->typid != default_typid || + returning->typmod != default_typmod) + { + /* + * We abuse CaseTestExpr here as placeholder to pass the result of + * jsonpath evaluation as input to the coercion expression. + */ + CaseTestExpr *placeholder = makeNode(CaseTestExpr); + + placeholder->typeId = default_typid; + placeholder->typeMod = default_typmod; + + coercion_expr = coerceJsonFuncExpr(pstate, (Node *) placeholder, + returning, false); + if (coercion_expr == (Node *) placeholder) + coercion_expr = NULL; + } + + jsexpr->coercion_expr = coercion_expr; + + if (coercion_expr == NULL) + { + /* + * Either no cast was found or coercion is unnecessary but still must + * convert the string value to the output type. + */ + if (omit_quotes || jsexpr->op == JSON_VALUE_OP) + jsexpr->use_io_coercion = true; + else + jsexpr->use_json_coercion = true; + } + + Assert(jsexpr->coercion_expr != NULL || + (jsexpr->use_io_coercion != jsexpr->use_json_coercion)); +} + +/* + * Transform a JSON BEHAVIOR clause. + */ +static JsonBehavior * +transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior, + JsonBehaviorType default_behavior, + JsonReturning *returning) +{ + JsonBehaviorType btype = default_behavior; + Node *expr = NULL; + bool coerce_at_runtime = false; + int location = -1; + + if (behavior) + { + btype = behavior->btype; + location = behavior->location; + if (btype == JSON_BEHAVIOR_DEFAULT) + { + expr = transformExprRecurse(pstate, behavior->expr); + if (!IsA(expr, Const) && !IsA(expr, FuncExpr) && + !IsA(expr, OpExpr)) + ereport(ERROR, + (errcode(ERRCODE_DATATYPE_MISMATCH), + errmsg("can only specify constant, non-aggregate" + " function, or operator expression for" + " DEFAULT"), + parser_errposition(pstate, exprLocation(expr)))); + if (contain_var_clause(expr)) + ereport(ERROR, + (errcode(ERRCODE_DATATYPE_MISMATCH), + errmsg("DEFAULT expression must not contain column references"), + parser_errposition(pstate, exprLocation(expr)))); + if (expression_returns_set(expr)) + ereport(ERROR, + (errcode(ERRCODE_DATATYPE_MISMATCH), + errmsg("DEFAULT expression must not return a set"), + parser_errposition(pstate, exprLocation(expr)))); + } + } + + if (expr == NULL && btype != JSON_BEHAVIOR_ERROR) + expr = GetJsonBehaviorConst(btype, location); + + if (expr) + { + Node *coerced_expr = expr; + bool isnull = (IsA(expr, Const) && ((Const *) expr)->constisnull); + + /* + * Coerce NULLs and "internal" (that is, not specified by the user) + * jsonb-valued expressions at runtime using json_populate_type(). + * + * For other (user-specified) non-NULL values, try to find a cast and + * error out if one is not found. + */ + if (isnull || + (exprType(expr) == JSONBOID && + btype == default_behavior)) + coerce_at_runtime = true; + else + coerced_expr = + coerce_to_target_type(pstate, expr, exprType(expr), + returning->typid, returning->typmod, + COERCION_EXPLICIT, COERCE_EXPLICIT_CAST, + exprLocation((Node *) behavior)); + + if (coerced_expr == NULL) + ereport(ERROR, + errcode(ERRCODE_CANNOT_COERCE), + errmsg("cannot cast behavior expression of type %s to %s", + format_type_be(exprType(expr)), + format_type_be(returning->typid)), + parser_errposition(pstate, exprLocation(expr))); + else + expr = coerced_expr; + } + + if (behavior) + behavior->expr = expr; + else + behavior = makeJsonBehavior(btype, expr, location); + + behavior->coerce = coerce_at_runtime; + + return behavior; +} + +/* + * Returns a Const node holding the value for the given non-ERROR + * JsonBehaviorType. + */ +static Node * +GetJsonBehaviorConst(JsonBehaviorType btype, int location) +{ + Datum val = (Datum) 0; + Oid typid = JSONBOID; + int len = -1; + bool isbyval = false; + bool isnull = false; + Const *con; + + switch (btype) + { + case JSON_BEHAVIOR_EMPTY_ARRAY: + val = DirectFunctionCall1(jsonb_in, CStringGetDatum("[]")); + break; + + case JSON_BEHAVIOR_EMPTY_OBJECT: + val = DirectFunctionCall1(jsonb_in, CStringGetDatum("{}")); + break; + + case JSON_BEHAVIOR_TRUE: + val = BoolGetDatum(true); + typid = BOOLOID; + len = sizeof(bool); + isbyval = true; + break; + + case JSON_BEHAVIOR_FALSE: + val = BoolGetDatum(false); + typid = BOOLOID; + len = sizeof(bool); + isbyval = true; + break; + + case JSON_BEHAVIOR_NULL: + case JSON_BEHAVIOR_UNKNOWN: + case JSON_BEHAVIOR_EMPTY: + val = (Datum) 0; + isnull = true; + typid = INT4OID; + len = sizeof(int32); + isbyval = true; + break; + + /* These two behavior types are handled by the caller. */ + case JSON_BEHAVIOR_DEFAULT: + case JSON_BEHAVIOR_ERROR: + Assert(false); + break; + + default: + elog(ERROR, "unrecognized SQL/JSON behavior %d", btype); + break; + } + + con = makeConst(typid, -1, InvalidOid, len, val, isnull, isbyval); + con->location = location; + + return (Node *) con; +} diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c index ea522b932b..1276f33604 100644 --- a/src/backend/parser/parse_target.c +++ b/src/backend/parser/parse_target.c @@ -2006,6 +2006,24 @@ FigureColnameInternal(Node *node, char **name) /* make JSON_ARRAYAGG act like a regular function */ *name = "json_arrayagg"; return 2; + case T_JsonFuncExpr: + /* make SQL/JSON functions act like a regular function */ + switch (((JsonFuncExpr *) node)->op) + { + case JSON_EXISTS_OP: + *name = "json_exists"; + return 2; + case JSON_QUERY_OP: + *name = "json_query"; + return 2; + case JSON_VALUE_OP: + *name = "json_value"; + return 2; + default: + elog(ERROR, "unrecognized JsonExpr op: %d", + (int) ((JsonFuncExpr *) node)->op); + } + break; default: break; } diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c index 8160d78ec6..79df80704d 100644 --- a/src/backend/utils/adt/formatting.c +++ b/src/backend/utils/adt/formatting.c @@ -4583,6 +4583,50 @@ parse_datetime(text *date_txt, text *fmt, Oid collid, bool strict, } } +/* + * Parses the datetime format string in 'fmt_str' and returns true if it + * contains a timezone specifier, false if not. + */ +bool +datetime_format_has_tz(const char *fmt_str) +{ + bool incache; + int fmt_len = strlen(fmt_str); + int result; + FormatNode *format; + + if (fmt_len > DCH_CACHE_SIZE) + { + /* + * Allocate new memory if format picture is bigger than static cache + * and do not use cache (call parser always) + */ + incache = false; + + format = (FormatNode *) palloc((fmt_len + 1) * sizeof(FormatNode)); + + parse_format(format, fmt_str, DCH_keywords, + DCH_suff, DCH_index, DCH_FLAG, NULL); + } + else + { + /* + * Use cache buffers + */ + DCHCacheEntry *ent = DCH_cache_fetch(fmt_str, false); + + incache = true; + format = ent->format; + } + + result = DCH_datetime_type(format); + + if (!incache) + pfree(format); + + return result & DCH_ZONED; +} + /* * do_to_timestamp: shared code for to_timestamp and to_date * diff --git a/src/backend/utils/adt/jsonb.c b/src/backend/utils/adt/jsonb.c index a941654d5a..e4562b3c6c 100644 --- a/src/backend/utils/adt/jsonb.c +++ b/src/backend/utils/adt/jsonb.c @@ -2158,3 +2158,34 @@ jsonb_float8(PG_FUNCTION_ARGS) PG_RETURN_DATUM(retValue); } + +/* + * Convert jsonb to a C-string stripping quotes from scalar strings. + */ +char * +JsonbUnquote(Jsonb *jb) +{ + if (JB_ROOT_IS_SCALAR(jb)) + { + JsonbValue v; + + (void) JsonbExtractScalar(&jb->root, &v); + + if (v.type == jbvString) + return pnstrdup(v.val.string.val, v.val.string.len); + else if (v.type == jbvBool) + return pstrdup(v.val.boolean ? "true" : "false"); + else if (v.type == jbvNumeric) + return DatumGetCString(DirectFunctionCall1(numeric_out, + PointerGetDatum(v.val.numeric))); + else if (v.type == jbvNull) + return pstrdup("null"); + else + { + elog(ERROR, "unrecognized jsonb value type %d", v.type); + return NULL; + } + } + else + return JsonbToCString(NULL, &jb->root, VARSIZE(jb)); +} diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c index 1b0f494329..83125b06a4 100644 --- a/src/backend/utils/adt/jsonfuncs.c +++ b/src/backend/utils/adt/jsonfuncs.c @@ -2830,7 +2830,9 @@ populate_array_dim_jsonb(PopulateArrayContext *ctx, /* context */ check_stack_depth(); - if (jbv->type != jbvBinary || !JsonContainerIsArray(jbc)) + /* Even scalars can end up here thanks to ExecEvalJsonCoercion(). */ + if (jbv->type != jbvBinary || !JsonContainerIsArray(jbc) || + JsonContainerIsScalar(jbc)) { populate_array_report_expected_array(ctx, ndim - 1); /* Getting here means the error was reported softly. */ @@ -2838,8 +2840,6 @@ populate_array_dim_jsonb(PopulateArrayContext *ctx, /* context */ return false; } - Assert(!JsonContainerIsScalar(jbc)); - it = JsonbIteratorInit(jbc); tok = JsonbIteratorNext(&it, &val, true); @@ -3323,6 +3323,62 @@ prepare_column_cache(ColumnIOData *column, ReleaseSysCache(tup); } +/* + * Populate and return the value of specified type from a given json/jsonb + * value 'json_val'. 'cache' is caller-specified pointer to save the + * ColumnIOData that will be initialized on the 1st call and then reused + * during any subsequent calls. 'mcxt' gives the memory context to allocate + * the ColumnIOData and any other subsidiary memory in. 'escontext', + * if not NULL, tells that any errors that occur should be handled softly. + */ +Datum +json_populate_type(Datum json_val, Oid json_type, + Oid typid, int32 typmod, + void **cache, MemoryContext mcxt, + bool *isnull, + Node *escontext) +{ + JsValue jsv = {0}; + JsonbValue jbv; + + jsv.is_json = json_type == JSONOID; + + if (*isnull) + { + if (jsv.is_json) + jsv.val.json.str = NULL; + else + jsv.val.jsonb = NULL; + } + else if (jsv.is_json) + { + text *json = DatumGetTextPP(json_val); + + jsv.val.json.str = VARDATA_ANY(json); + jsv.val.json.len = VARSIZE_ANY_EXHDR(json); + jsv.val.json.type = JSON_TOKEN_INVALID; /* not used in + * populate_composite() */ + } + else + { + Jsonb *jsonb = DatumGetJsonbP(json_val); + + jsv.val.jsonb = &jbv; + + /* fill binary jsonb value pointing to jb */ + jbv.type = jbvBinary; + jbv.val.binary.data = &jsonb->root; + jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ; + } + + if (*cache == NULL) + *cache = MemoryContextAllocZero(mcxt, sizeof(ColumnIOData)); + + return populate_record_field(*cache, typid, typmod, NULL, mcxt, + PointerGetDatum(NULL), &jsv, isnull, + escontext); +} + /* recursively populate a record field or an array element from a json/jsonb value */ static Datum populate_record_field(ColumnIOData *col, diff --git a/src/backend/utils/adt/jsonpath.c b/src/backend/utils/adt/jsonpath.c index 786a2b65c6..11e6193e96 100644 --- a/src/backend/utils/adt/jsonpath.c +++ b/src/backend/utils/adt/jsonpath.c @@ -63,11 +63,14 @@ #include "postgres.h" +#include "catalog/pg_type.h" #include "lib/stringinfo.h" #include "libpq/pqformat.h" #include "miscadmin.h" #include "nodes/miscnodes.h" +#include "nodes/nodeFuncs.h" #include "utils/fmgrprotos.h" +#include "utils/formatting.h" #include "utils/json.h" #include "utils/jsonpath.h" @@ -1239,3 +1242,281 @@ jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from, JsonPathItem *to, return true; } + +/* SQL/JSON datatype status: */ +enum JsonPathDatatypeStatus +{ + jpdsNonDateTime, /* null, bool, numeric, string, array, object */ + jpdsUnknownDateTime, /* unknown datetime type */ + jpdsDateTimeZoned, /* timetz, timestamptz */ + jpdsDateTimeNonZoned, /* time, timestamp, date */ +}; + +/* Context for jspIsMutableWalker() */ +struct JsonPathMutableContext +{ + List *varnames; /* list of variable names */ + List *varexprs; /* list of variable expressions */ + enum JsonPathDatatypeStatus current; /* status of @ item */ + bool lax; /* jsonpath is lax or strict */ + bool mutable; /* resulting mutability status */ +}; + +static enum JsonPathDatatypeStatus jspIsMutableWalker(JsonPathItem *jpi, + struct JsonPathMutableContext *cxt); + +/* + * Function to check whether jsonpath expression is mutable to be used in the + * planner function contain_mutable_functions(). + */ +bool +jspIsMutable(JsonPath *path, List *varnames, List *varexprs) +{ + struct JsonPathMutableContext cxt; + JsonPathItem jpi; + + cxt.varnames = varnames; + cxt.varexprs = varexprs; + cxt.current = jpdsNonDateTime; + cxt.lax = (path->header & JSONPATH_LAX) != 0; + cxt.mutable = false; + + jspInit(&jpi, path); + (void) jspIsMutableWalker(&jpi, &cxt); + + return cxt.mutable; +} + +/* + * Recursive walker for jspIsMutable() + */ +static enum JsonPathDatatypeStatus +jspIsMutableWalker(JsonPathItem *jpi, struct JsonPathMutableContext *cxt) +{ + JsonPathItem next; + enum JsonPathDatatypeStatus status = jpdsNonDateTime; + + while (!cxt->mutable) + { + JsonPathItem arg; + enum JsonPathDatatypeStatus leftStatus; + enum JsonPathDatatypeStatus rightStatus; + + switch (jpi->type) + { + case jpiRoot: + Assert(status == jpdsNonDateTime); + break; + + case jpiCurrent: + Assert(status == jpdsNonDateTime); + status = cxt->current; + break; + + case jpiFilter: + { + enum JsonPathDatatypeStatus prevStatus = cxt->current; + + cxt->current = status; + jspGetArg(jpi, &arg); + jspIsMutableWalker(&arg, cxt); + + cxt->current = prevStatus; + break; + } + + case jpiVariable: + { + int32 len; + const char *name = jspGetString(jpi, &len); + ListCell *lc1; + ListCell *lc2; + + Assert(status == jpdsNonDateTime); + + forboth(lc1, cxt->varnames, lc2, cxt->varexprs) + { + String *varname = lfirst_node(String, lc1); + Node *varexpr = lfirst(lc2); + + if (strncmp(varname->sval, name, len)) + continue; + + switch (exprType(varexpr)) + { + case DATEOID: + case TIMEOID: + case TIMESTAMPOID: + status = jpdsDateTimeNonZoned; + break; + + case TIMETZOID: + case TIMESTAMPTZOID: + status = jpdsDateTimeZoned; + break; + + default: + status = jpdsNonDateTime; + break; + } + + break; + } + break; + } + + case jpiEqual: + case jpiNotEqual: + case jpiLess: + case jpiGreater: + case jpiLessOrEqual: + case jpiGreaterOrEqual: + Assert(status == jpdsNonDateTime); + jspGetLeftArg(jpi, &arg); + leftStatus = jspIsMutableWalker(&arg, cxt); + + jspGetRightArg(jpi, &arg); + rightStatus = jspIsMutableWalker(&arg, cxt); + + /* + * Comparison of datetime type with different timezone status + * is mutable. + */ + if (leftStatus != jpdsNonDateTime && + rightStatus != jpdsNonDateTime && + (leftStatus == jpdsUnknownDateTime || + rightStatus == jpdsUnknownDateTime || + leftStatus != rightStatus)) + cxt->mutable = true; + break; + + case jpiNot: + case jpiIsUnknown: + case jpiExists: + case jpiPlus: + case jpiMinus: + Assert(status == jpdsNonDateTime); + jspGetArg(jpi, &arg); + jspIsMutableWalker(&arg, cxt); + break; + + case jpiAnd: + case jpiOr: + case jpiAdd: + case jpiSub: + case jpiMul: + case jpiDiv: + case jpiMod: + case jpiStartsWith: + Assert(status == jpdsNonDateTime); + jspGetLeftArg(jpi, &arg); + jspIsMutableWalker(&arg, cxt); + jspGetRightArg(jpi, &arg); + jspIsMutableWalker(&arg, cxt); + break; + + case jpiIndexArray: + for (int i = 0; i < jpi->content.array.nelems; i++) + { + JsonPathItem from; + JsonPathItem to; + + if (jspGetArraySubscript(jpi, &from, &to, i)) + jspIsMutableWalker(&to, cxt); + + jspIsMutableWalker(&from, cxt); + } + /* FALLTHROUGH */ + + case jpiAnyArray: + if (!cxt->lax) + status = jpdsNonDateTime; + break; + + case jpiAny: + if (jpi->content.anybounds.first > 0) + status = jpdsNonDateTime; + break; + + case jpiDatetime: + if (jpi->content.arg) + { + char *template; + + jspGetArg(jpi, &arg); + if (arg.type != jpiString) + { + status = jpdsNonDateTime; + break; /* there will be runtime error */ + } + + template = jspGetString(&arg, NULL); + if (datetime_format_has_tz(template)) + status = jpdsDateTimeZoned; + else + status = jpdsDateTimeNonZoned; + } + else + { + status = jpdsUnknownDateTime; + } + break; + + case jpiLikeRegex: + Assert(status == jpdsNonDateTime); + jspInitByBuffer(&arg, jpi->base, jpi->content.like_regex.expr); + jspIsMutableWalker(&arg, cxt); + break; + + /* literals */ + case jpiNull: + case jpiString: + case jpiNumeric: + case jpiBool: + break; + /* accessors */ + case jpiKey: + case jpiAnyKey: + /* special items */ + case jpiSubscript: + case jpiLast: + /* item methods */ + case jpiType: + case jpiSize: + case jpiAbs: + case jpiFloor: + case jpiCeiling: + case jpiDouble: + case jpiKeyValue: + case jpiBigint: + case jpiBoolean: + case jpiDecimal: + case jpiInteger: + case jpiNumber: + case jpiStringFunc: + status = jpdsNonDateTime; + break; + + case jpiTime: + case jpiDate: + case jpiTimestamp: + status = jpdsDateTimeNonZoned; + cxt->mutable = true; + break; + + case jpiTimeTz: + case jpiTimestampTz: + status = jpdsDateTimeNonZoned; + cxt->mutable = true; + break; + + } + + if (!jspGetNext(jpi, &next)) + break; + + jpi = &next; + } + + return status; +} diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c index 6c8bd57503..1d2d0245e8 100644 --- a/src/backend/utils/adt/jsonpath_exec.c +++ b/src/backend/utils/adt/jsonpath_exec.c @@ -229,6 +229,12 @@ static JsonPathExecResult appendBoolResult(JsonPathExecContext *cxt, JsonPathItem *jsp, JsonValueList *found, JsonPathBool res); static void getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item, JsonbValue *value); +static JsonbValue *GetJsonPathVar(void *cxt, char *varName, int varNameLen, + JsonbValue *baseObject, int *baseObjectId); +static int CountJsonPathVars(void *cxt); +static void JsonItemFromDatum(Datum val, Oid typid, int32 typmod, + JsonbValue *res); +static void JsonbValueInitNumericDatum(JsonbValue *jbv, Datum num); static void getJsonPathVariable(JsonPathExecContext *cxt, JsonPathItem *variable, JsonbValue *value); static int countVariablesFromJsonb(void *varsJsonb); @@ -2860,6 +2866,155 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item, } } +/* + * Returns the computed value of a JSON path variable with given name. + */ +static JsonbValue * +GetJsonPathVar(void *cxt, char *varName, int varNameLen, + JsonbValue *baseObject, int *baseObjectId) +{ + JsonPathVariable *var = NULL; + List *vars = cxt; + ListCell *lc; + JsonbValue *result; + int id = 1; + + foreach(lc, vars) + { + JsonPathVariable *curvar = lfirst(lc); + + if (!strncmp(curvar->name, varName, varNameLen)) + { + var = curvar; + break; + } + + id++; + } + + if (var == NULL) + { + *baseObjectId = -1; + return NULL; + } + + result = palloc(sizeof(JsonbValue)); + if (var->isnull) + { + *baseObjectId = 0; + result->type = jbvNull; + } + else + JsonItemFromDatum(var->value, var->typid, var->typmod, result); + + *baseObject = *result; + *baseObjectId = id; + + return result; +} + +static int +CountJsonPathVars(void *cxt) +{ + List *vars = (List *) cxt; + + return list_length(vars); +} + + +/* + * Initialize JsonbValue to pass to jsonpath executor from given + * datum value of the specified type. + */ +static void +JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res) +{ + switch (typid) + { + case BOOLOID: + res->type = jbvBool; + res->val.boolean = DatumGetBool(val); + break; + case NUMERICOID: + JsonbValueInitNumericDatum(res, val); + break; + case INT2OID: + JsonbValueInitNumericDatum(res, DirectFunctionCall1(int2_numeric, val)); + break; + case INT4OID: + JsonbValueInitNumericDatum(res, DirectFunctionCall1(int4_numeric, val)); + break; + case INT8OID: + JsonbValueInitNumericDatum(res, DirectFunctionCall1(int8_numeric, val)); + break; + case FLOAT4OID: + JsonbValueInitNumericDatum(res, DirectFunctionCall1(float4_numeric, val)); + break; + case FLOAT8OID: + JsonbValueInitNumericDatum(res, DirectFunctionCall1(float8_numeric, val)); + break; + case TEXTOID: + case VARCHAROID: + res->type = jbvString; + res->val.string.val = VARDATA_ANY(val); + res->val.string.len = VARSIZE_ANY_EXHDR(val); + break; + case DATEOID: + case TIMEOID: + case TIMETZOID: + case TIMESTAMPOID: + case TIMESTAMPTZOID: + res->type = jbvDatetime; + res->val.datetime.value = val; + res->val.datetime.typid = typid; + res->val.datetime.typmod = typmod; + res->val.datetime.tz = 0; + break; + case JSONBOID: + { + JsonbValue *jbv = res; + Jsonb *jb = DatumGetJsonbP(val); + + if (JsonContainerIsScalar(&jb->root)) + { + bool result PG_USED_FOR_ASSERTS_ONLY; + + result = JsonbExtractScalar(&jb->root, jbv); + Assert(result); + } + else + JsonbInitBinary(jbv, jb); + break; + } + case JSONOID: + { + text *txt = DatumGetTextP(val); + char *str = text_to_cstring(txt); + Jsonb *jb; + + jb = DatumGetJsonbP(DirectFunctionCall1(jsonb_in, + CStringGetDatum(str))); + pfree(str); + + JsonItemFromDatum(JsonbPGetDatum(jb), JSONBOID, -1, res); + break; + } + default: + ereport(ERROR, + errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("could not convert value of type %s to jsonpath", + format_type_be(typid))); + } +} + +/* Initialize numeric value from the given datum */ +static void +JsonbValueInitNumericDatum(JsonbValue *jbv, Datum num) +{ + jbv->type = jbvNumeric; + jbv->val.numeric = DatumGetNumeric(num); +} + /* * Get the value of variable passed to jsonpath executor */ @@ -3596,3 +3751,170 @@ compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2, return DatumGetInt32(DirectFunctionCall2(cmpfunc, val1, val2)); } + +/* + * Executor-callable JSON_EXISTS implementation + * + * Returns NULL instead of throwing errors if 'error' is not NULL, setting + * *error to true. + */ +bool +JsonPathExists(Datum jb, JsonPath *jp, bool *error, List *vars) +{ + JsonPathExecResult res; + + res = executeJsonPath(jp, vars, + GetJsonPathVar, CountJsonPathVars, + DatumGetJsonbP(jb), !error, NULL, true); + + Assert(error || !jperIsError(res)); + + if (error && jperIsError(res)) + *error = true; + + return res == jperOk; +} + +/* + * Executor-callable JSON_QUERY implementation + * + * Returns NULL instead of throwing errors if 'error' is not NULL, setting + * *error to true. *empty is set to true if no match is found. + */ +Datum +JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper, bool *empty, + bool *error, List *vars) +{ + JsonbValue *singleton; + bool wrap; + JsonValueList found = {0}; + JsonPathExecResult res; + int count; + + res = executeJsonPath(jp, vars, + GetJsonPathVar, CountJsonPathVars, + DatumGetJsonbP(jb), !error, &found, true); + Assert(error || !jperIsError(res)); + if (error && jperIsError(res)) + { + *error = true; + *empty = false; + return (Datum) 0; + } + + /* WRAP or not? */ + count = JsonValueListLength(&found); + singleton = count > 0 ? JsonValueListHead(&found) : NULL; + if (singleton == NULL) + wrap = false; + else if (wrapper == JSW_NONE || wrapper == JSW_UNSPEC) + wrap = false; + else if (wrapper == JSW_UNCONDITIONAL) + wrap = true; + else if (wrapper == JSW_CONDITIONAL) + wrap = count > 1 || + IsAJsonbScalar(singleton) || + (singleton->type == jbvBinary && + JsonContainerIsScalar(singleton->val.binary.data)); + else + { + elog(ERROR, "unrecognized json wrapper %d", wrapper); + wrap = false; + } + + if (wrap) + return JsonbPGetDatum(JsonbValueToJsonb(wrapItemsInArray(&found))); + + /* No wrapping means only one item is expected. */ + if (count > 1) + { + if (error) + { + *error = true; + return (Datum) 0; + } + + ereport(ERROR, + (errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM), + errmsg("JSON path expression in JSON_QUERY should return singleton item without wrapper"), + errhint("Use WITH WRAPPER clause to wrap SQL/JSON item sequence into array."))); + } + + if (singleton) + return JsonbPGetDatum(JsonbValueToJsonb(singleton)); + + *empty = true; + return PointerGetDatum(NULL); +} + +/* + * Executor-callable JSON_VALUE implementation + * + * Returns NULL instead of throwing errors if 'error' is not NULL, setting + * *error to true. *empty is set to true if no match is found. + */ +JsonbValue * +JsonPathValue(Datum jb, JsonPath *jp, bool *empty, bool *error, List *vars) +{ + JsonbValue *res; + JsonValueList found = {0}; + JsonPathExecResult jper PG_USED_FOR_ASSERTS_ONLY; + int count; + + jper = executeJsonPath(jp, vars, GetJsonPathVar, CountJsonPathVars, + DatumGetJsonbP(jb), + !error, &found, true); + + Assert(error || !jperIsError(jper)); + + if (error && jperIsError(jper)) + { + *error = true; + *empty = false; + return NULL; + } + + count = JsonValueListLength(&found); + + *empty = (count == 0); + + if (*empty) + return NULL; + + /* JSON_VALUE expects to get only singletons. */ + if (count > 1) + { + if (error) + { + *error = true; + return NULL; + } + + ereport(ERROR, + (errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM), + errmsg("JSON path expression in JSON_VALUE should return singleton scalar item"))); + } + + res = JsonValueListHead(&found); + if (res->type == jbvBinary && JsonContainerIsScalar(res->val.binary.data)) + JsonbExtractScalar(res->val.binary.data, res); + + /* JSON_VALUE expects to get only scalars. */ + if (!IsAJsonbScalar(res)) + { + if (error) + { + *error = true; + return NULL; + } + + ereport(ERROR, + (errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED), + errmsg("JSON path expression in JSON_VALUE should return singleton scalar item"))); + } + + if (res->type == jbvNull) + return NULL; + + return res; +} diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c index 07b454418d..4a7402e09e 100644 --- a/src/backend/utils/adt/ruleutils.c +++ b/src/backend/utils/adt/ruleutils.c @@ -478,6 +478,8 @@ static void get_const_expr(Const *constval, deparse_context *context, int showtype); static void get_const_collation(Const *constval, deparse_context *context); static void get_json_format(JsonFormat *format, StringInfo buf); +static void get_json_returning(JsonReturning *returning, StringInfo buf, + bool json_format_by_default); static void get_json_constructor(JsonConstructorExpr *ctor, deparse_context *context, bool showimplicit); static void get_json_constructor_options(JsonConstructorExpr *ctor, @@ -520,6 +522,8 @@ static char *generate_qualified_type_name(Oid typid); static text *string_to_text(char *str); static char *flatten_reloptions(Oid relid); static void get_reloptions(StringInfo buf, Datum reloptions); +static void get_json_path_spec(Node *path_spec, deparse_context *context, + bool showimplicit); #define only_marker(rte) ((rte)->inh ? "" : "ONLY ") @@ -8466,6 +8470,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags) case T_MergeSupportFunc: case T_FuncExpr: case T_JsonConstructorExpr: + case T_JsonExpr: /* function-like: name(..) or name[..] */ return true; @@ -8637,6 +8642,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags) case T_GroupingFunc: /* own parentheses */ case T_WindowFunc: /* own parentheses */ case T_CaseExpr: /* other separators */ + case T_JsonExpr: /* own parentheses */ return true; default: return false; @@ -8752,6 +8758,64 @@ get_rule_expr_paren(Node *node, deparse_context *context, appendStringInfoChar(context->buf, ')'); } +static void +get_json_behavior(JsonBehavior *behavior, deparse_context *context, + const char *on) +{ + /* + * The order of array elements must correspond to the order of + * JsonBehaviorType members. + */ + const char *behavior_names[] = + { + " NULL", + " ERROR", + " EMPTY", + " TRUE", + " FALSE", + " UNKNOWN", + " EMPTY ARRAY", + " EMPTY OBJECT", + " DEFAULT " + }; + + if ((int) behavior->btype < 0 || behavior->btype >= lengthof(behavior_names)) + elog(ERROR, "invalid json behavior type: %d", behavior->btype); + + appendStringInfoString(context->buf, behavior_names[behavior->btype]); + + if (behavior->btype == JSON_BEHAVIOR_DEFAULT) + get_rule_expr(behavior->expr, context, false); + + appendStringInfo(context->buf, " ON %s", on); +} + +/* + * get_json_expr_options + * + * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS. + */ +static void +get_json_expr_options(JsonExpr *jsexpr, deparse_context *context, + JsonBehaviorType default_behavior) +{ + if (jsexpr->op == JSON_QUERY_OP) + { + if (jsexpr->wrapper == JSW_CONDITIONAL) + appendStringInfo(context->buf, " WITH CONDITIONAL WRAPPER"); + else if (jsexpr->wrapper == JSW_UNCONDITIONAL) + appendStringInfo(context->buf, " WITH UNCONDITIONAL WRAPPER"); + + if (jsexpr->omit_quotes) + appendStringInfo(context->buf, " OMIT QUOTES"); + } + + if (jsexpr->on_empty && jsexpr->on_empty->btype != default_behavior) + get_json_behavior(jsexpr->on_empty, context, "EMPTY"); + + if (jsexpr->on_error && jsexpr->on_error->btype != default_behavior) + get_json_behavior(jsexpr->on_error, context, "ERROR"); +} /* ---------- * get_rule_expr - Parse back an expression @@ -10031,6 +10095,67 @@ get_rule_expr(Node *node, deparse_context *context, } break; + case T_JsonExpr: + { + JsonExpr *jexpr = (JsonExpr *) node; + + switch (jexpr->op) + { + case JSON_EXISTS_OP: + appendStringInfoString(buf, "JSON_EXISTS("); + break; + case JSON_QUERY_OP: + appendStringInfoString(buf, "JSON_QUERY("); + break; + case JSON_VALUE_OP: + appendStringInfoString(buf, "JSON_VALUE("); + break; + default: + elog(ERROR, "unrecognized JsonExpr op: %d", + (int) jexpr->op); + } + + get_rule_expr(jexpr->formatted_expr, context, showimplicit); + + appendStringInfoString(buf, ", "); + + get_json_path_spec(jexpr->path_spec, context, showimplicit); + + if (jexpr->passing_values) + { + ListCell *lc1, + *lc2; + bool needcomma = false; + + appendStringInfoString(buf, " PASSING "); + + forboth(lc1, jexpr->passing_names, + lc2, jexpr->passing_values) + { + if (needcomma) + appendStringInfoString(buf, ", "); + needcomma = true; + + get_rule_expr((Node *) lfirst(lc2), context, showimplicit); + appendStringInfo(buf, " AS %s", + ((String *) lfirst_node(String, lc1))->sval); + } + } + + if (jexpr->op != JSON_EXISTS_OP || + jexpr->returning->typid != BOOLOID) + get_json_returning(jexpr->returning, context->buf, + jexpr->op == JSON_QUERY_OP); + + get_json_expr_options(jexpr, context, + jexpr->op != JSON_EXISTS_OP ? + JSON_BEHAVIOR_NULL : + JSON_BEHAVIOR_FALSE); + + appendStringInfoString(buf, ")"); + } + break; + case T_List: { char *sep; @@ -10154,6 +10279,7 @@ looks_like_function(Node *node) case T_MinMaxExpr: case T_SQLValueFunction: case T_XmlExpr: + case T_JsonExpr: /* these are all accepted by func_expr_common_subexpr */ return true; default: @@ -11023,6 +11149,18 @@ get_const_collation(Const *constval, deparse_context *context) } } +/* + * get_json_path_spec - Parse back a JSON path specification + */ +static void +get_json_path_spec(Node *path_spec, deparse_context *context, bool showimplicit) +{ + if (IsA(path_spec, Const)) + get_const_expr((Const *) path_spec, context, -1); + else + get_rule_expr(path_spec, context, showimplicit); +} + /* * get_json_format - Parse back a JsonFormat node */ diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h index 8953d76738..64698202a5 100644 --- a/src/include/executor/execExpr.h +++ b/src/include/executor/execExpr.h @@ -240,6 +240,9 @@ typedef enum ExprEvalOp EEOP_XMLEXPR, EEOP_JSON_CONSTRUCTOR, EEOP_IS_JSON, + EEOP_JSONEXPR_PATH, + EEOP_JSONEXPR_COERCION, + EEOP_JSONEXPR_COERCION_FINISH, EEOP_AGGREF, EEOP_GROUPING_FUNC, EEOP_WINDOW_FUNC, @@ -693,6 +696,20 @@ typedef struct ExprEvalStep JsonIsPredicate *pred; /* original expression node */ } is_json; + /* for EEOP_JSONEXPR_PATH */ + struct + { + struct JsonExprState *jsestate; + } jsonexpr; + + /* for EEOP_JSONEXPR_COERCION */ + struct + { + Oid targettype; + int32 targettypmod; + void *json_populate_type_cache; + ErrorSaveContext *escontext; + } jsonexpr_coercion; } d; } ExprEvalStep; @@ -810,6 +827,11 @@ extern void ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op); extern void ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op, ExprContext *econtext); extern void ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op); +extern int ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op, + ExprContext *econtext); +extern void ExecEvalJsonCoercion(ExprState *state, ExprEvalStep *op, + ExprContext *econtext); +extern void ExecEvalJsonCoercionFinish(ExprState *state, ExprEvalStep *op); extern void ExecEvalGroupingFunc(ExprState *state, ExprEvalStep *op); extern void ExecEvalMergeSupportFunc(ExprState *state, ExprEvalStep *op, ExprContext *econtext); diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h index 9259352672..1774c56ae3 100644 --- a/src/include/nodes/execnodes.h +++ b/src/include/nodes/execnodes.h @@ -1008,6 +1008,79 @@ typedef struct DomainConstraintState ExprState *check_exprstate; /* check_expr's eval state, or NULL */ } DomainConstraintState; +/* + * State for JsonExpr evaluation, too big to inline. + * + * This contains the information going into and coming out of the + * EEOP_JSONEXPR_PATH eval step. + */ +typedef struct JsonExprState +{ + /* original expression node */ + JsonExpr *jsexpr; + + /* value/isnull for formatted_expr */ + NullableDatum formatted_expr; + + /* value/isnull for pathspec */ + NullableDatum pathspec; + + /* JsonPathVariable entries for passing_values */ + List *args; + + /* + * Output variables that drive the EEOP_JUMP_IF_NOT_TRUE steps that are + * added for ON ERROR and ON EMPTY expressions, if any. + * + * Reset for each evaluation of EEOP_JSONEXPR_PATH. + */ + + /* Set to true if jsonpath evaluation cause an error. */ + NullableDatum error; + + /* Set to true if the jsonpath evaluation returned 0 items. */ + NullableDatum empty; + + /* + * Addresses of steps that implement the non-ERROR variant of ON EMPTY and + * ON ERROR behaviors, respectively. + */ + int jump_empty; + int jump_error; + + /* + * Address of the step to coerce the result value of jsonpath evaluation + * to the RETURNING type using JsonExpr.coercion_expr. -1 if no coercion + * is necessary or if either JsonExpr.use_io_coercion or + * JsonExpr.use_json_coercion is true. + */ + int jump_eval_coercion; + + /* + * Address to jump to when skipping all the steps after performing + * ExecEvalJsonExprPath() so as to return whatever the JsonPath* function + * returned as is, that is, in the cases where there's no error and no + * coercion is necessary. + */ + int jump_end; + + /* + * RETURNING type input function invocation info when + * JsonExpr.use_io_coercion is true. + */ + FmgrInfo *input_finfo; + FunctionCallInfo input_fcinfo; + + /* + * For error-safe evaluation of coercions. When the ON ERROR behavior is + * not ERROR, a pointer to this is passed to ExecInitExprRec() when + * initializing the coercion expressions or to ExecInitJsonCoercion(). + * + * Reset for each evaluation of EEOP_JSONEXPR_PATH. + */ + ErrorSaveContext escontext; +} JsonExprState; + /* ---------------------------------------------------------------- * Executor State Trees diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h index 2dc79648d2..fdc78270e5 100644 --- a/src/include/nodes/makefuncs.h +++ b/src/include/nodes/makefuncs.h @@ -116,5 +116,7 @@ extern Node *makeJsonKeyValue(Node *key, Node *value); extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format, JsonValueType item_type, bool unique_keys, int location); +extern JsonBehavior *makeJsonBehavior(JsonBehaviorType btype, Node *expr, + int location); #endif /* MAKEFUNC_H */ diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index 1e2e898851..9b709f0390 100644 --- a/src/include/nodes/parsenodes.h +++ b/src/include/nodes/parsenodes.h @@ -1715,6 +1715,48 @@ typedef struct JsonOutput JsonReturning *returning; /* RETURNING FORMAT clause and type Oids */ } JsonOutput; +/* + * JsonArgument - + * representation of argument from JSON PASSING clause + */ +typedef struct JsonArgument +{ + NodeTag type; + JsonValueExpr *val; /* argument value expression */ + char *name; /* argument name */ +} JsonArgument; + +/* + * JsonQuotes - + * representation of [KEEP|OMIT] QUOTES clause for JSON_QUERY() + */ +typedef enum JsonQuotes +{ + JS_QUOTES_UNSPEC, /* unspecified */ + JS_QUOTES_KEEP, /* KEEP QUOTES */ + JS_QUOTES_OMIT, /* OMIT QUOTES */ +} JsonQuotes; + +/* + * JsonFuncExpr - + * untransformed representation of function expressions for + * SQL/JSON query functions + */ +typedef struct JsonFuncExpr +{ + NodeTag type; + JsonExprOp op; /* expression type */ + JsonValueExpr *context_item; /* context item expression */ + Node *pathspec; /* JSON path specification expression */ + List *passing; /* list of PASSING clause arguments, if any */ + JsonOutput *output; /* output clause, if specified */ + JsonBehavior *on_empty; /* ON EMPTY behavior */ + JsonBehavior *on_error; /* ON ERROR behavior */ + JsonWrapper wrapper; /* array wrapper behavior (JSON_QUERY only) */ + JsonQuotes quotes; /* omit or keep quotes? (JSON_QUERY only) */ + int location; /* token location, or -1 if unknown */ +} JsonFuncExpr; + /* * JsonKeyValue - * untransformed representation of JSON object key-value pair for diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h index e57d69f72e..376f67e6a5 100644 --- a/src/include/nodes/primnodes.h +++ b/src/include/nodes/primnodes.h @@ -1691,6 +1691,128 @@ typedef struct JsonIsPredicate ParseLoc location; /* token location, or -1 if unknown */ } JsonIsPredicate; +/* Nodes used in SQL/JSON query functions */ + +/* + * JsonWrapper - + * representation of WRAPPER clause for JSON_QUERY() + */ +typedef enum JsonWrapper +{ + JSW_UNSPEC, + JSW_NONE, + JSW_CONDITIONAL, + JSW_UNCONDITIONAL, +} JsonWrapper; + +/* + * JsonBehaviorType - + * enumeration of behavior types used in SQL/JSON ON ERROR/EMPTY clauses + * + * If enum members are reordered, get_json_behavior() from ruleutils.c + * must be updated accordingly. + */ +typedef enum JsonBehaviorType +{ + JSON_BEHAVIOR_NULL = 0, + JSON_BEHAVIOR_ERROR, + JSON_BEHAVIOR_EMPTY, + JSON_BEHAVIOR_TRUE, + JSON_BEHAVIOR_FALSE, + JSON_BEHAVIOR_UNKNOWN, + JSON_BEHAVIOR_EMPTY_ARRAY, + JSON_BEHAVIOR_EMPTY_OBJECT, + JSON_BEHAVIOR_DEFAULT, +} JsonBehaviorType; + +/* + * JsonBehavior + * Specifications for ON ERROR / ON EMPTY behaviors of SQL/JSON + * query functions specified by a JsonExpr + * + * 'expr' is the expression to emit when a given behavior (EMPTY or ERROR) + * occurs on evaluating the SQL/JSON query function. 'coerce' is set to true + * if 'expr' isn't already of the expected target type given by + * JsonExpr.returning. + */ +typedef struct JsonBehavior +{ + NodeTag type; + + JsonBehaviorType btype; + Node *expr; + bool coerce; + int location; /* token location, or -1 if unknown */ +} JsonBehavior; + +/* + * JsonExprOp - + * enumeration of SQL/JSON query function types + */ +typedef enum JsonExprOp +{ + JSON_EXISTS_OP, /* JSON_EXISTS() */ + JSON_QUERY_OP, /* JSON_QUERY() */ + JSON_VALUE_OP, /* JSON_VALUE() */ +} JsonExprOp; + +/* + * JsonExpr - + * Transformed representation of JSON_VALUE(), JSON_QUERY(), and + * JSON_EXISTS() + */ +typedef struct JsonExpr +{ + Expr xpr; + + JsonExprOp op; + + /* jsonb-valued expression to query */ + Node *formatted_expr; + + /* Format of the above expression needed by ruleutils.c */ + JsonFormat *format; + + /* jsopath-valued expression containing the query pattern */ + Node *path_spec; + + /* Expected type/format of the output. */ + JsonReturning *returning; + + /* Information about the PASSING argument expressions */ + List *passing_names; + List *passing_values; + + /* User-specified or default ON EMPTY and ON ERROR behaviors */ + JsonBehavior *on_empty; + JsonBehavior *on_error; + + /* + * Information about converting the result of jsonpath functions + * JsonPathQuery() and JsonPathValue() to the RETURNING type. + * + * coercion_expr is a cast expression if the parser can find it for the + * source and the target type. If not, either use_io_coercion or + * use_json_coercion is set to determine the coercion method to use at + * runtime; see coerceJsonExprOutput() and ExecInitJsonExpr(). + */ + Node *coercion_expr; + bool use_io_coercion; + bool use_json_coercion; + + /* WRAPPER specification for JSON_QUERY */ + JsonWrapper wrapper; + + /* KEEP or OMIT QUOTES for singleton scalars returned by JSON_QUERY() */ + bool omit_quotes; + + /* JsonExpr's collation, if coercion_expr is NULL. */ + Oid collation; + + /* Original JsonFuncExpr's location */ + int location; +} JsonExpr; + /* ---------------- * NullTest * diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index 099353469b..3941ef18d0 100644 --- a/src/include/parser/kwlist.h +++ b/src/include/parser/kwlist.h @@ -93,6 +93,7 @@ PG_KEYWORD("commit", COMMIT, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("committed", COMMITTED, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("compression", COMPRESSION, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("concurrently", CONCURRENTLY, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL) +PG_KEYWORD("conditional", CONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("configuration", CONFIGURATION, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("conflict", CONFLICT, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("connection", CONNECTION, UNRESERVED_KEYWORD, BARE_LABEL) @@ -147,11 +148,13 @@ PG_KEYWORD("double", DOUBLE_P, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("drop", DROP, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("each", EACH, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("else", ELSE, RESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("empty", EMPTY_P, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("enable", ENABLE_P, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("encoding", ENCODING, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("encrypted", ENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("end", END_P, RESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("enum", ENUM_P, UNRESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("error", ERROR_P, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("escape", ESCAPE, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("event", EVENT, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("except", EXCEPT, RESERVED_KEYWORD, AS_LABEL) @@ -233,10 +236,14 @@ PG_KEYWORD("join", JOIN, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL) PG_KEYWORD("json", JSON, COL_NAME_KEYWORD, BARE_LABEL) PG_KEYWORD("json_array", JSON_ARRAY, COL_NAME_KEYWORD, BARE_LABEL) PG_KEYWORD("json_arrayagg", JSON_ARRAYAGG, COL_NAME_KEYWORD, BARE_LABEL) +PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD, BARE_LABEL) PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD, BARE_LABEL) PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL) +PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL) PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL) PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL) +PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL) +PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("keys", KEYS, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("label", LABEL, UNRESERVED_KEYWORD, BARE_LABEL) @@ -303,6 +310,7 @@ PG_KEYWORD("off", OFF, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("offset", OFFSET, RESERVED_KEYWORD, AS_LABEL) PG_KEYWORD("oids", OIDS, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("old", OLD, UNRESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("omit", OMIT, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("on", ON, RESERVED_KEYWORD, AS_LABEL) PG_KEYWORD("only", ONLY, RESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("operator", OPERATOR, UNRESERVED_KEYWORD, BARE_LABEL) @@ -345,6 +353,7 @@ PG_KEYWORD("procedures", PROCEDURES, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("program", PROGRAM, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("publication", PUBLICATION, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("quote", QUOTE, UNRESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("quotes", QUOTES, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("range", RANGE, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("read", READ, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("real", REAL, COL_NAME_KEYWORD, BARE_LABEL) @@ -415,6 +424,7 @@ PG_KEYWORD("stdout", STDOUT, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("storage", STORAGE, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("stored", STORED, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("strict", STRICT_P, UNRESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("string", STRING_P, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("strip", STRIP_P, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("subscription", SUBSCRIPTION, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("substring", SUBSTRING, COL_NAME_KEYWORD, BARE_LABEL) @@ -450,6 +460,7 @@ PG_KEYWORD("types", TYPES_P, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("uescape", UESCAPE, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("unbounded", UNBOUNDED, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("uncommitted", UNCOMMITTED, UNRESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("unconditional", UNCONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("unencrypted", UNENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("union", UNION, RESERVED_KEYWORD, AS_LABEL) PG_KEYWORD("unique", UNIQUE, RESERVED_KEYWORD, BARE_LABEL) diff --git a/src/include/utils/formatting.h b/src/include/utils/formatting.h index 7ea1a70f71..cde030414e 100644 --- a/src/include/utils/formatting.h +++ b/src/include/utils/formatting.h @@ -29,5 +29,6 @@ extern char *asc_initcap(const char *buff, size_t nbytes); extern Datum parse_datetime(text *date_txt, text *fmt, Oid collid, bool strict, Oid *typid, int32 *typmod, int *tz, struct Node *escontext); +extern bool datetime_format_has_tz(const char *fmt_str); #endif diff --git a/src/include/utils/jsonb.h b/src/include/utils/jsonb.h index e38dfd4901..d589ace5a2 100644 --- a/src/include/utils/jsonb.h +++ b/src/include/utils/jsonb.h @@ -422,6 +422,7 @@ extern char *JsonbToCString(StringInfo out, JsonbContainer *in, int estimated_len); extern char *JsonbToCStringIndent(StringInfo out, JsonbContainer *in, int estimated_len); +extern char *JsonbUnquote(Jsonb *jb); extern bool JsonbExtractScalar(JsonbContainer *jbc, JsonbValue *res); extern const char *JsonbTypeName(JsonbValue *val); diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h index 31c1ae4767..190e13284b 100644 --- a/src/include/utils/jsonfuncs.h +++ b/src/include/utils/jsonfuncs.h @@ -15,6 +15,7 @@ #define JSONFUNCS_H #include "common/jsonapi.h" +#include "nodes/nodes.h" #include "utils/jsonb.h" /* @@ -88,4 +89,10 @@ extern Datum datum_to_jsonb(Datum val, JsonTypeCategory tcategory, Oid outfuncoid); extern Datum jsonb_from_text(text *js, bool unique_keys); +extern Datum json_populate_type(Datum json_val, Oid json_type, + Oid typid, int32 typmod, + void **cache, MemoryContext mcxt, + bool *isnull, + Node *escontext); + #endif diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h index 0f0e126e03..0f4b1ebc9f 100644 --- a/src/include/utils/jsonpath.h +++ b/src/include/utils/jsonpath.h @@ -16,6 +16,7 @@ #include "fmgr.h" #include "nodes/pg_list.h" +#include "nodes/primnodes.h" #include "utils/jsonb.h" typedef struct @@ -202,6 +203,7 @@ extern bool jspGetBool(JsonPathItem *v); extern char *jspGetString(JsonPathItem *v, int32 *len); extern bool jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from, JsonPathItem *to, int i); +extern bool jspIsMutable(JsonPath *path, List *varnames, List *varexprs); extern const char *jspOperationName(JsonPathItemType type); @@ -279,4 +281,26 @@ extern bool jspConvertRegexFlags(uint32 xflags, int *result, struct Node *escontext); +/* + * Evaluation of jsonpath + */ + +/* External variable passed into jsonpath. */ +typedef struct JsonPathVariable +{ + char *name; + Oid typid; + int32 typmod; + Datum value; + bool isnull; +} JsonPathVariable; + + +/* SQL/JSON item */ +extern bool JsonPathExists(Datum jb, JsonPath *path, bool *error, List *vars); +extern Datum JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper, + bool *empty, bool *error, List *vars); +extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty, + bool *error, List *vars); + #endif diff --git a/src/interfaces/ecpg/preproc/ecpg.trailer b/src/interfaces/ecpg/preproc/ecpg.trailer index 435c139ec2..b2aa44f36d 100644 --- a/src/interfaces/ecpg/preproc/ecpg.trailer +++ b/src/interfaces/ecpg/preproc/ecpg.trailer @@ -651,6 +651,34 @@ var_type: simple_type $$.type_index = mm_strdup("-1"); $$.type_sizeof = NULL; } + | STRING_P + { + if (INFORMIX_MODE) + { + /* In Informix mode, "string" is automatically a typedef */ + $$.type_enum = ECPGt_string; + $$.type_str = mm_strdup("char"); + $$.type_dimension = mm_strdup("-1"); + $$.type_index = mm_strdup("-1"); + $$.type_sizeof = NULL; + } + else + { + /* Otherwise, legal only if user typedef'ed it */ + struct typedefs *this = get_typedef("string", false); + + $$.type_str = (this->type->type_enum == ECPGt_varchar || this->type->type_enum == ECPGt_bytea) ? EMPTY : mm_strdup(this->name); + $$.type_enum = this->type->type_enum; + $$.type_dimension = this->type->type_dimension; + $$.type_index = this->type->type_index; + if (this->type->type_sizeof && strlen(this->type->type_sizeof) != 0) + $$.type_sizeof = this->type->type_sizeof; + else + $$.type_sizeof = cat_str(3, mm_strdup("sizeof("), mm_strdup(this->name), mm_strdup(")")); + + struct_member_list[struct_level] = ECPGstruct_member_dup(this->struct_member_list); + } + } | INTERVAL ecpg_interval { $$.type_enum = ECPGt_interval; diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out new file mode 100644 index 0000000000..5a537d0655 --- /dev/null +++ b/src/test/regress/expected/sqljson_queryfuncs.out @@ -0,0 +1,1269 @@ +-- JSON_EXISTS +SELECT JSON_EXISTS(NULL::jsonb, '$'); + json_exists +------------- + +(1 row) + +SELECT JSON_EXISTS(jsonb '[]', '$'); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$'); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS(jsonb '1', '$'); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS(jsonb 'null', '$'); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS(jsonb '[]', '$'); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS(jsonb '1', '$.a'); + json_exists +------------- + f +(1 row) + +SELECT JSON_EXISTS(jsonb '1', 'strict $.a'); -- FALSE on error + json_exists +------------- + f +(1 row) + +SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR); +ERROR: jsonpath member accessor can only be applied to an object +SELECT JSON_EXISTS(jsonb 'null', '$.a'); + json_exists +------------- + f +(1 row) + +SELECT JSON_EXISTS(jsonb '[]', '$.a'); + json_exists +------------- + f +(1 row) + +SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a'); -- FALSE on error + json_exists +------------- + f +(1 row) + +SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a'); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS(jsonb '{}', '$.a'); + json_exists +------------- + f +(1 row) + +SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a'); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS(jsonb '1', '$.a.b'); + json_exists +------------- + f +(1 row) + +SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b'); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b'); + json_exists +------------- + f +(1 row) + +SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x); + json_exists +------------- + f +(1 row) + +SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y); + json_exists +------------- + f +(1 row) + +-- extension: boolean expressions +SELECT JSON_EXISTS(jsonb '1', '$ > 2'); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR); + json_exists +------------- + t +(1 row) + +-- JSON_VALUE +SELECT JSON_VALUE(NULL::jsonb, '$'); + json_value +------------ + +(1 row) + +SELECT JSON_VALUE(jsonb 'null', '$'); + json_value +------------ + +(1 row) + +SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int); + json_value +------------ + +(1 row) + +SELECT JSON_VALUE(jsonb 'true', '$'); + json_value +------------ + t +(1 row) + +SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool); + json_value +------------ + t +(1 row) + +SELECT JSON_VALUE(jsonb '123', '$'); + json_value +------------ + 123 +(1 row) + +SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234; + ?column? +---------- + 357 +(1 row) + +SELECT JSON_VALUE(jsonb '123', '$' RETURNING text); + json_value +------------ + 123 +(1 row) + +/* jsonb bytea ??? */ +SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR); + json_value +------------ + \x313233 +(1 row) + +SELECT JSON_VALUE(jsonb '1.23', '$'); + json_value +------------ + 1.23 +(1 row) + +SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int); + json_value +------------ + +(1 row) + +SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric); + json_value +------------ + 1.23 +(1 row) + +SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR); +ERROR: invalid input syntax for type integer: "1.23" +SELECT JSON_VALUE(jsonb '"aaa"', '$'); + json_value +------------ + aaa +(1 row) + +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text); + json_value +------------ + aaa +(1 row) + +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5)); + json_value +------------ + aaa +(1 row) + +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2)); + json_value +------------ + aa +(1 row) + +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json); + json_value +------------ + "aaa" +(1 row) + +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb); + json_value +------------ + "aaa" +(1 row) + +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR); + json_value +------------ + "aaa" +(1 row) + +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR); + json_value +------------ + "aaa" +(1 row) + +SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json); + json_value +------------ + "\"aaa\"" +(1 row) + +SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb); + json_value +------------ + "\"aaa\"" +(1 row) + +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int); + json_value +------------ + +(1 row) + +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR); +ERROR: invalid input syntax for type integer: "aaa" +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR); + json_value +------------ + 111 +(1 row) + +SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234; + ?column? +---------- + 357 +(1 row) + +SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9; + ?column? +------------ + 03-01-2017 +(1 row) + +-- Test NULL checks execution in domain types +CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL; +SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null); + json_value +------------ + +(1 row) + +SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null ERROR ON ERROR); +ERROR: domain sqljsonb_int_not_null does not allow null values +SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null DEFAULT 2 ON EMPTY ERROR ON ERROR); +ERROR: domain sqljsonb_int_not_null does not allow null values +SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT 2 ON EMPTY ERROR ON ERROR); + json_value +------------ + 2 +(1 row) + +SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON EMPTY ERROR ON ERROR); +ERROR: domain sqljsonb_int_not_null does not allow null values +CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple'); +CREATE DOMAIN rgb AS rainbow CHECK (VALUE IN ('red', 'green', 'blue')); +SELECT JSON_VALUE('"purple"'::jsonb, 'lax $[*]' RETURNING rgb); + json_value +------------ + +(1 row) + +SELECT JSON_VALUE('"purple"'::jsonb, 'lax $[*]' RETURNING rgb ERROR ON ERROR); +ERROR: value for domain rgb violates check constraint "rgb_check" +SELECT JSON_VALUE(jsonb '[]', '$'); + json_value +------------ + +(1 row) + +SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR); +ERROR: JSON path expression in JSON_VALUE should return singleton scalar item +SELECT JSON_VALUE(jsonb '{}', '$'); + json_value +------------ + +(1 row) + +SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR); +ERROR: JSON path expression in JSON_VALUE should return singleton scalar item +SELECT JSON_VALUE(jsonb '1', '$.a'); + json_value +------------ + +(1 row) + +SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR); +ERROR: jsonpath member accessor can only be applied to an object +SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR); + json_value +------------ + error +(1 row) + +SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR); +ERROR: no SQL/JSON item +SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR); +ERROR: no SQL/JSON item +SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR); + json_value +------------ + 2 +(1 row) + +SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR); + json_value +------------ + 2 +(1 row) + +SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR); + json_value +------------ + 2 +(1 row) + +SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR); + json_value +------------ + +(1 row) + +SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR); + json_value +------------ + 2 +(1 row) + +SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR); +ERROR: no SQL/JSON item +SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR); +ERROR: JSON path expression in JSON_VALUE should return singleton scalar item +SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR); + json_value +------------ + 0 +(1 row) + +SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR); +ERROR: invalid input syntax for type integer: " " +SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR); + json_value +------------ + 5 +(1 row) + +SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR); + json_value +------------ + 1 +(1 row) + +SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int FORMAT JSON); -- RETURNING FORMAT not allowed +ERROR: cannot specify FORMAT JSON in RETURNING clause of JSON_VALUE() +LINE 1: ...CT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int FORMAT JSO... + ^ +-- RETUGNING pseudo-types not allowed +SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING record); +ERROR: returning pseudo-types is not supported in SQL/JSON functions +SELECT + x, + JSON_VALUE( + jsonb '{"a": 1, "b": 2}', + '$.* ? (@ > $x)' PASSING x AS x + RETURNING int + DEFAULT -1 ON EMPTY + DEFAULT -2 ON ERROR + ) y +FROM + generate_series(0, 2) x; + x | y +---+---- + 0 | -2 + 1 | 2 + 2 | -1 +(3 rows) + +SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a); + json_value +------------ + (1,2) +(1 row) + +SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point); + json_value +------------ + (1,2) +(1 row) + +SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point ERROR ON ERROR); + json_value +------------ + (1,2) +(1 row) + +-- Test PASSING and RETURNING date/time types +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts); + json_value +------------------------------ + Tue Feb 20 18:34:56 2018 PST +(1 row) + +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz); + json_value +------------------------------ + Tue Feb 20 18:34:56 2018 PST +(1 row) + +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp); + json_value +-------------------------- + Tue Feb 20 18:34:56 2018 +(1 row) + +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING date '2018-02-21 12:34:56 +10' AS ts RETURNING date); + json_value +------------ + 02-21-2018 +(1 row) + +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING time '2018-02-21 12:34:56 +10' AS ts RETURNING time); + json_value +------------ + 12:34:56 +(1 row) + +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timetz '2018-02-21 12:34:56 +10' AS ts RETURNING timetz); + json_value +------------- + 12:34:56+10 +(1 row) + +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamp '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp); + json_value +-------------------------- + Wed Feb 21 12:34:56 2018 +(1 row) + +-- Also test RETURNING json[b] +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json); + json_value +----------------------------- + "2018-02-21T02:34:56+00:00" +(1 row) + +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb); + json_value +----------------------------- + "2018-02-21T02:34:56+00:00" +(1 row) + +-- Test that numeric JSON values are coerced uniformly +select json_value('{"a": 1.234}', '$.a' returning int error on error); +ERROR: invalid input syntax for type integer: "1.234" +select json_value('{"a": "1.234"}', '$.a' returning int error on error); +ERROR: invalid input syntax for type integer: "1.234" +-- JSON_QUERY +SELECT JSON_VALUE(NULL::jsonb, '$'); + json_value +------------ + +(1 row) + +SELECT + JSON_QUERY(js, '$'), + JSON_QUERY(js, '$' WITHOUT WRAPPER), + JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER), + JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER), + JSON_QUERY(js, '$' WITH ARRAY WRAPPER) +FROM + (VALUES + (jsonb 'null'), + ('12.3'), + ('true'), + ('"aaa"'), + ('[1, null, "2"]'), + ('{"a": 1, "b": [2]}') + ) foo(js); + json_query | json_query | json_query | json_query | json_query +--------------------+--------------------+--------------------+----------------------+---------------------- + null | null | [null] | [null] | [null] + 12.3 | 12.3 | [12.3] | [12.3] | [12.3] + true | true | [true] | [true] | [true] + "aaa" | "aaa" | ["aaa"] | ["aaa"] | ["aaa"] + [1, null, "2"] | [1, null, "2"] | [1, null, "2"] | [[1, null, "2"]] | [[1, null, "2"]] + {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}] +(6 rows) + +SELECT + JSON_QUERY(js, 'strict $[*]') AS "unspec", + JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without", + JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond", + JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond", + JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with" +FROM + (VALUES + (jsonb '1'), + ('[]'), + ('[null]'), + ('[12.3]'), + ('[true]'), + ('["aaa"]'), + ('[[1, 2, 3]]'), + ('[{"a": 1, "b": [2]}]'), + ('[1, "2", null, [3]]') + ) foo(js); + unspec | without | with cond | with uncond | with +--------------------+--------------------+---------------------+----------------------+---------------------- + | | | | + | | | | + null | null | [null] | [null] | [null] + 12.3 | 12.3 | [12.3] | [12.3] | [12.3] + true | true | [true] | [true] | [true] + "aaa" | "aaa" | ["aaa"] | ["aaa"] | ["aaa"] + [1, 2, 3] | [1, 2, 3] | [1, 2, 3] | [[1, 2, 3]] | [[1, 2, 3]] + {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}] + | | [1, "2", null, [3]] | [1, "2", null, [3]] | [1, "2", null, [3]] +(9 rows) + +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text); + json_query +------------ + "aaa" +(1 row) + +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES); + json_query +------------ + "aaa" +(1 row) + +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING); + json_query +------------ + "aaa" +(1 row) + +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES); + json_query +------------ + aaa +(1 row) + +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING); + json_query +------------ + aaa +(1 row) + +SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR); +ERROR: invalid input syntax for type json +DETAIL: Token "aaa" is invalid. +CONTEXT: JSON data, line 1: aaa +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR); +ERROR: invalid input syntax for type json +DETAIL: Token "aaa" is invalid. +CONTEXT: JSON data, line 1: aaa +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR); + json_query +------------ + \x616161 +(1 row) + +-- Behavior when a RETURNING type has typmod != -1 +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2)); + json_query +------------ + "a +(1 row) + +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2) OMIT QUOTES); + json_query +------------ + aa +(1 row) + +SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bbb' ON EMPTY); + json_query +------------ + bb +(1 row) + +SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bbb"'::jsonb ON EMPTY); + json_query +------------ + "b +(1 row) + +-- QUOTES behavior should not be specified when WITH WRAPPER used: +-- Should fail +SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES); +ERROR: SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used +LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES)... + ^ +SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES); +ERROR: SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used +LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES)... + ^ +SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES); +ERROR: SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used +LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER ... + ^ +SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES); +ERROR: SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used +LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER ... + ^ +-- Should succeed +SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES); + json_query +------------ + [1] +(1 row) + +SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES); + json_query +------------ + [1] +(1 row) + +-- test QUOTES behavior. +SELECT JSON_QUERY(jsonb'{"rec": "{1,2,3}"}', '$.rec' returning int[] omit quotes); + json_query +------------ + {1,2,3} +(1 row) + +SELECT JSON_QUERY(jsonb'{"rec": "{1,2,3}"}', '$.rec' returning int[] keep quotes); + json_query +------------ + +(1 row) + +SELECT JSON_QUERY(jsonb'{"rec": "{1,2,3}"}', '$.rec' returning int[] keep quotes error on error); +ERROR: expected JSON array +SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range omit quotes); + json_query +------------ + [1,3) +(1 row) + +SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range keep quotes); + json_query +------------ + +(1 row) + +SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range keep quotes error on error); +ERROR: malformed range literal: ""[1,2]"" +DETAIL: Missing left parenthesis or bracket. +SELECT JSON_QUERY(jsonb '[]', '$[*]'); + json_query +------------ + +(1 row) + +SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY); + json_query +------------ + +(1 row) + +SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY); + json_query +------------ + [] +(1 row) + +SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY); + json_query +------------ + [] +(1 row) + +SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY); + json_query +------------ + {} +(1 row) + +SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY); +ERROR: no SQL/JSON item +SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY); + json_query +------------ + "empty" +(1 row) + +SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR); +ERROR: no SQL/JSON item +SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR); +ERROR: no SQL/JSON item +SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR); +ERROR: no SQL/JSON item +SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR); +ERROR: no SQL/JSON item +SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR); +ERROR: no SQL/JSON item +SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR); +ERROR: JSON path expression in JSON_QUERY should return singleton item without wrapper +HINT: Use WITH WRAPPER clause to wrap SQL/JSON item sequence into array. +SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR); + json_query +------------ + "empty" +(1 row) + +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json); + json_query +------------ + [1, 2] +(1 row) + +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON); + json_query +------------ + [1, 2] +(1 row) + +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb); + json_query +------------ + [1, 2] +(1 row) + +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON); + json_query +------------ + [1, 2] +(1 row) + +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text); + json_query +------------ + [1, 2] +(1 row) + +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10)); + json_query +------------ + [1, 2] +(1 row) + +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3)); + json_query +------------ + [1, +(1 row) + +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON); + json_query +------------ + [1, 2] +(1 row) + +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea); + json_query +---------------- + \x5b312c20325d +(1 row) + +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON); + json_query +---------------- + \x5b312c20325d +(1 row) + +SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR); +ERROR: cannot cast behavior expression of type jsonb to bytea +LINE 1: ... JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJE... + ^ +SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR); +ERROR: cannot cast behavior expression of type jsonb to bytea +LINE 1: ...jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJE... + ^ +SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR); + json_query +------------ + {} +(1 row) + +SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR); + json_query +------------ + {} +(1 row) + +SELECT JSON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR); +ERROR: cannot cast behavior expression of type jsonb to bigint[] +LINE 1: ...ON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJE... + ^ +SELECT JSON_QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR); +ERROR: cannot cast behavior expression of type jsonb to bigint[] +LINE 1: ..._QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJE... + ^ +-- Coercion fails with quotes on +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int2 error on error); +ERROR: invalid input syntax for type smallint: ""123.1"" +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int4 error on error); +ERROR: invalid input syntax for type integer: ""123.1"" +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int8 error on error); +ERROR: invalid input syntax for type bigint: ""123.1"" +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING bool error on error); +ERROR: invalid input syntax for type boolean: ""123.1"" +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING numeric error on error); +ERROR: invalid input syntax for type numeric: ""123.1"" +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING real error on error); +ERROR: invalid input syntax for type real: ""123.1"" +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING float8 error on error); +ERROR: invalid input syntax for type double precision: ""123.1"" +-- Fine with OMIT QUOTES +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int2 omit quotes error on error); +ERROR: invalid input syntax for type smallint: "123.1" +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING float8 omit quotes error on error); + json_query +------------ + 123.1 +(1 row) + +-- RETUGNING pseudo-types not allowed +SELECT JSON_QUERY(jsonb '[3,4]', '$[*]' RETURNING anyarray EMPTY OBJECT ON ERROR); +ERROR: returning pseudo-types is not supported in SQL/JSON functions +SELECT + x, y, + JSON_QUERY( + jsonb '[1,2,3,4,5,null]', + '$[*] ? (@ >= $x && @ <= $y)' + PASSING x AS x, y AS y + WITH CONDITIONAL WRAPPER + EMPTY ARRAY ON EMPTY + ) list +FROM + generate_series(0, 4) x, + generate_series(0, 4) y; + x | y | list +---+---+-------------- + 0 | 0 | [] + 0 | 1 | [1] + 0 | 2 | [1, 2] + 0 | 3 | [1, 2, 3] + 0 | 4 | [1, 2, 3, 4] + 1 | 0 | [] + 1 | 1 | [1] + 1 | 2 | [1, 2] + 1 | 3 | [1, 2, 3] + 1 | 4 | [1, 2, 3, 4] + 2 | 0 | [] + 2 | 1 | [] + 2 | 2 | [2] + 2 | 3 | [2, 3] + 2 | 4 | [2, 3, 4] + 3 | 0 | [] + 3 | 1 | [] + 3 | 2 | [] + 3 | 3 | [3] + 3 | 4 | [3, 4] + 4 | 0 | [] + 4 | 1 | [] + 4 | 2 | [] + 4 | 3 | [] + 4 | 4 | [4] +(25 rows) + +-- record type returning with quotes behavior. +CREATE TYPE comp_abc AS (a text, b int, c timestamp); +SELECT JSON_QUERY(jsonb'{"rec": "(abc,42,01.02.2003)"}', '$.rec' returning comp_abc omit quotes); + json_query +------------------------------------- + (abc,42,"Thu Jan 02 00:00:00 2003") +(1 row) + +SELECT JSON_QUERY(jsonb'{"rec": "(abc,42,01.02.2003)"}', '$.rec' returning comp_abc keep quotes); + json_query +------------ + +(1 row) + +SELECT JSON_QUERY(jsonb'{"rec": "(abc,42,01.02.2003)"}', '$.rec' returning comp_abc keep quotes error on error); +ERROR: cannot call populate_composite on a scalar +DROP TYPE comp_abc; +-- Extension: record types returning +CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]); +CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]); +SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}}, {"a": 2}]', '$[0]' RETURNING sqljsonb_rec); + json_query +----------------------------------------------------- + (1,aaa,"[1, ""2"", {}]","{""x"": [1, ""2"", {}]}",) +(1 row) + +SELECT JSON_QUERY(jsonb '[{"a": "a", "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}}, {"a": 2}]', '$[0]' RETURNING sqljsonb_rec ERROR ON ERROR); +ERROR: invalid input syntax for type integer: "a" +SELECT JSON_QUERY(jsonb '[{"a": "a", "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}}, {"a": 2}]', '$[0]' RETURNING sqljsonb_rec); + json_query +------------ + +(1 row) + +SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa": [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa); + unnest +------------------------ + {"a": 1, "b": ["foo"]} + {"a": 2, "c": {}} + 123 +(3 rows) + +SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca); + a | t | js | jb | jsa +---+-------------+----+------------+----- + 1 | ["foo", []] | | | + 2 | | | [{}, true] | +(2 rows) + +SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}}, {"a": 2}]', '$[0]' RETURNING jsonpath); + json_query +------------ + +(1 row) + +SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}}, {"a": 2}]', '$[0]' RETURNING jsonpath ERROR ON ERROR); +ERROR: syntax error at or near "{" of jsonpath input +-- Extension: array types returning +SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER); + json_query +-------------- + {1,2,NULL,3} +(1 row) + +SELECT JSON_QUERY(jsonb '[1,2,null,"a"]', '$[*]' RETURNING int[] WITH WRAPPER ERROR ON ERROR); +ERROR: invalid input syntax for type integer: "a" +SELECT JSON_QUERY(jsonb '[1,2,null,"a"]', '$[*]' RETURNING int[] WITH WRAPPER); + json_query +------------ + +(1 row) + +SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[])); + a | t | js | jb | jsa +---+-------------+----+------------+----- + 1 | ["foo", []] | | | + 2 | | | [{}, true] | +(2 rows) + +-- Extension: domain types returning +SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null); + json_query +------------ + 1 +(1 row) + +SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null); + json_query +------------ + +(1 row) + +SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null ERROR ON ERROR); +ERROR: no SQL/JSON item +-- Test timestamptz passing and output +SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts); + json_query +----------------------------- + "2018-02-21T02:34:56+00:00" +(1 row) + +SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json); + json_query +----------------------------- + "2018-02-21T02:34:56+00:00" +(1 row) + +SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb); + json_query +----------------------------- + "2018-02-21T02:34:56+00:00" +(1 row) + +-- Test constraints +CREATE TABLE test_jsonb_constraints ( + js text, + i int, + x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER) + CONSTRAINT test_jsonb_constraint1 + CHECK (js IS JSON) + CONSTRAINT test_jsonb_constraint2 + CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr)) + CONSTRAINT test_jsonb_constraint3 + CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT '12' ON EMPTY ERROR ON ERROR) > i) + CONSTRAINT test_jsonb_constraint4 + CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]') + CONSTRAINT test_jsonb_constraint5 + CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > 'a' COLLATE "C") +); +\d test_jsonb_constraints + Table "public.test_jsonb_constraints" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+-------------------------------------------------------------------------------- + js | text | | | + i | integer | | | + x | jsonb | | | JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER) +Check constraints: + "test_jsonb_constraint1" CHECK (js IS JSON) + "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS int, i::text AS txt, ARRAY[1, 2, 3] AS arr)) + "test_jsonb_constraint3" CHECK (JSON_VALUE(js::jsonb, '$."a"' RETURNING integer DEFAULT 12 ON EMPTY ERROR ON ERROR) > i) + "test_jsonb_constraint4" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb) + "test_jsonb_constraint5" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")) + +SELECT check_clause +FROM information_schema.check_constraints +WHERE constraint_name LIKE 'test_jsonb_constraint%' +ORDER BY 1; + check_clause +------------------------------------------------------------------------------------------------------------------------ + (JSON_QUERY((js)::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")) + (JSON_QUERY((js)::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb) + (JSON_VALUE((js)::jsonb, '$."a"' RETURNING integer DEFAULT 12 ON EMPTY ERROR ON ERROR) > i) + (js IS JSON) + JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS int, (i)::text AS txt, ARRAY[1, 2, 3] AS arr) +(5 rows) + +SELECT pg_get_expr(adbin, adrelid) +FROM pg_attrdef +WHERE adrelid = 'test_jsonb_constraints'::regclass +ORDER BY 1; + pg_get_expr +-------------------------------------------------------------------------------- + JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER) +(1 row) + +INSERT INTO test_jsonb_constraints VALUES ('', 1); +ERROR: new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint1" +DETAIL: Failing row contains (, 1, [1, 2]). +INSERT INTO test_jsonb_constraints VALUES ('1', 1); +ERROR: new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2" +DETAIL: Failing row contains (1, 1, [1, 2]). +INSERT INTO test_jsonb_constraints VALUES ('[]'); +ERROR: new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2" +DETAIL: Failing row contains ([], null, [1, 2]). +INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1); +ERROR: new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2" +DETAIL: Failing row contains ({"b": 1}, 1, [1, 2]). +INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1); +ERROR: new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3" +DETAIL: Failing row contains ({"a": 1}, 1, [1, 2]). +INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1); +ERROR: new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5" +DETAIL: Failing row contains ({"a": 7}, 1, [1, 2]). +INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1); +ERROR: new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4" +DETAIL: Failing row contains ({"a": 10}, 1, [1, 2]). +DROP TABLE test_jsonb_constraints; +-- Test mutabilily of query functions +CREATE TABLE test_jsonb_mutability(js jsonb, b int); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.time()')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.date()')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.time_tz()')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.timestamp()')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.timestamp_tz()')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.date() < $.time_tz())')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.date() < $.time())')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.time() < $.time())')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.time() < $.time_tz())')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp() < $.timestamp_tz())')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp_tz() < $.timestamp_tz())')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.time() < $.datetime("HH:MI TZH"))')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.date() < $.datetime("HH:MI TZH"))')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp() < $.datetime("HH:MI TZH"))')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp() < $.datetime("HH:MI"))')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp_tz() < $.datetime("HH:MI TZH"))')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp_tz() < $.datetime("HH:MI"))')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.date() < $x' PASSING '12:34'::timetz AS x)); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.date() < $x' PASSING '1234'::int AS x)); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp(2) < $.timestamp(3))')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))')); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x)); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x)); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x)); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x)); +ERROR: functions in index expression must be marked IMMUTABLE +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_VALUE(js, '$' DEFAULT random()::int ON ERROR)); +ERROR: functions in index expression must be marked IMMUTABLE +-- DEFAULT expression +CREATE OR REPLACE FUNCTION ret_setint() RETURNS SETOF integer AS +$$ +BEGIN + RETURN QUERY EXECUTE 'select 1 union all select 1'; +END; +$$ +LANGUAGE plpgsql IMMUTABLE; +SELECT JSON_QUERY(js, '$' RETURNING int DEFAULT ret_setint() ON ERROR) FROM test_jsonb_mutability; +ERROR: DEFAULT expression must not return a set +LINE 1: SELECT JSON_QUERY(js, '$' RETURNING int DEFAULT ret_setint(... + ^ +SELECT JSON_QUERY(js, '$' RETURNING int DEFAULT b + 1 ON ERROR) FROM test_jsonb_mutability; +ERROR: DEFAULT expression must not contain column references +LINE 1: SELECT JSON_QUERY(js, '$' RETURNING int DEFAULT b + 1 ON ER... + ^ +SELECT JSON_QUERY(js, '$' RETURNING int DEFAULT sum(1) over() ON ERROR) FROM test_jsonb_mutability; +ERROR: can only specify constant, non-aggregate function, or operator expression for DEFAULT +LINE 1: SELECT JSON_QUERY(js, '$' RETURNING int DEFAULT sum(1) over... + ^ +SELECT JSON_QUERY(js, '$' RETURNING int DEFAULT (SELECT 1) ON ERROR) FROM test_jsonb_mutability; +ERROR: can only specify constant, non-aggregate function, or operator expression for DEFAULT +LINE 1: SELECT JSON_QUERY(js, '$' RETURNING int DEFAULT (SELECT 1) ... + ^ +DROP TABLE test_jsonb_mutability; +DROP FUNCTION ret_setint; +-- Extension: non-constant JSON path +SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a'); + json_exists +------------- + t +(1 row) + +SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a'); + json_value +------------ + 123 +(1 row) + +SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY); + json_value +------------ + foo +(1 row) + +SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a'); + json_query +------------ + 123 +(1 row) + +SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER); + json_query +------------ + [123] +(1 row) + +-- Should fail (invalid path) +SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error'); +ERROR: syntax error at or near " " of jsonpath input +-- Non-jsonb inputs automatically coerced to jsonb +SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a'); + json_exists +------------- + t +(1 row) + +SELECT JSON_QUERY(NULL FORMAT JSON, '$'); + json_query +------------ + +(1 row) + +-- Test non-const jsonpath +CREATE TEMP TABLE jsonpaths (path) AS SELECT '$'; +SELECT json_value('"aaa"', path RETURNING json) FROM jsonpaths; + json_value +------------ + "aaa" +(1 row) + diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule index e48cb4b7a3..5ac6e871f5 100644 --- a/src/test/regress/parallel_schedule +++ b/src/test/regress/parallel_schedule @@ -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 +test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath sqljson sqljson_queryfuncs # ---------- # Another group of parallel tests diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql new file mode 100644 index 0000000000..d01b172376 --- /dev/null +++ b/src/test/regress/sql/sqljson_queryfuncs.sql @@ -0,0 +1,428 @@ +-- JSON_EXISTS +SELECT JSON_EXISTS(NULL::jsonb, '$'); +SELECT JSON_EXISTS(jsonb '[]', '$'); +SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$'); + +SELECT JSON_EXISTS(jsonb '1', '$'); +SELECT JSON_EXISTS(jsonb 'null', '$'); +SELECT JSON_EXISTS(jsonb '[]', '$'); + +SELECT JSON_EXISTS(jsonb '1', '$.a'); +SELECT JSON_EXISTS(jsonb '1', 'strict $.a'); -- FALSE on error +SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR); +SELECT JSON_EXISTS(jsonb 'null', '$.a'); +SELECT JSON_EXISTS(jsonb '[]', '$.a'); +SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a'); -- FALSE on error +SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a'); +SELECT JSON_EXISTS(jsonb '{}', '$.a'); +SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a'); + +SELECT JSON_EXISTS(jsonb '1', '$.a.b'); +SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b'); +SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b'); + +SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x); +SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x); +SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y); +SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y); + +-- extension: boolean expressions +SELECT JSON_EXISTS(jsonb '1', '$ > 2'); +SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR); + +-- JSON_VALUE +SELECT JSON_VALUE(NULL::jsonb, '$'); + +SELECT JSON_VALUE(jsonb 'null', '$'); +SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int); + +SELECT JSON_VALUE(jsonb 'true', '$'); +SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool); + +SELECT JSON_VALUE(jsonb '123', '$'); +SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234; +SELECT JSON_VALUE(jsonb '123', '$' RETURNING text); +/* jsonb bytea ??? */ +SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR); + +SELECT JSON_VALUE(jsonb '1.23', '$'); +SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int); +SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric); +SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR); + +SELECT JSON_VALUE(jsonb '"aaa"', '$'); +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text); +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5)); +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2)); +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json); +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb); +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR); +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR); +SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json); +SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb); +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int); +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR); +SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR); +SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234; + +SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9; + +-- Test NULL checks execution in domain types +CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL; +SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null); +SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null ERROR ON ERROR); +SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null DEFAULT 2 ON EMPTY ERROR ON ERROR); +SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT 2 ON EMPTY ERROR ON ERROR); +SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON EMPTY ERROR ON ERROR); +CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple'); +CREATE DOMAIN rgb AS rainbow CHECK (VALUE IN ('red', 'green', 'blue')); +SELECT JSON_VALUE('"purple"'::jsonb, 'lax $[*]' RETURNING rgb); +SELECT JSON_VALUE('"purple"'::jsonb, 'lax $[*]' RETURNING rgb ERROR ON ERROR); + +SELECT JSON_VALUE(jsonb '[]', '$'); +SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR); +SELECT JSON_VALUE(jsonb '{}', '$'); +SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR); + +SELECT JSON_VALUE(jsonb '1', '$.a'); +SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR); +SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR); +SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR); +SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR); +SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR); +SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR); +SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR); +SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR); +SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR); +SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR); + +SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR); +SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR); +SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR); +SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR); +SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR); +SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int FORMAT JSON); -- RETURNING FORMAT not allowed + +-- RETUGNING pseudo-types not allowed +SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING record); + +SELECT + x, + JSON_VALUE( + jsonb '{"a": 1, "b": 2}', + '$.* ? (@ > $x)' PASSING x AS x + RETURNING int + DEFAULT -1 ON EMPTY + DEFAULT -2 ON ERROR + ) y +FROM + generate_series(0, 2) x; + +SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a); +SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point); +SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point ERROR ON ERROR); + +-- Test PASSING and RETURNING date/time types +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts); +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz); +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp); +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING date '2018-02-21 12:34:56 +10' AS ts RETURNING date); +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING time '2018-02-21 12:34:56 +10' AS ts RETURNING time); +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timetz '2018-02-21 12:34:56 +10' AS ts RETURNING timetz); +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamp '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp); + +-- Also test RETURNING json[b] +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json); +SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb); + +-- Test that numeric JSON values are coerced uniformly +select json_value('{"a": 1.234}', '$.a' returning int error on error); +select json_value('{"a": "1.234"}', '$.a' returning int error on error); + +-- JSON_QUERY + +SELECT JSON_VALUE(NULL::jsonb, '$'); + +SELECT + JSON_QUERY(js, '$'), + JSON_QUERY(js, '$' WITHOUT WRAPPER), + JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER), + JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER), + JSON_QUERY(js, '$' WITH ARRAY WRAPPER) +FROM + (VALUES + (jsonb 'null'), + ('12.3'), + ('true'), + ('"aaa"'), + ('[1, null, "2"]'), + ('{"a": 1, "b": [2]}') + ) foo(js); + +SELECT + JSON_QUERY(js, 'strict $[*]') AS "unspec", + JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without", + JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond", + JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond", + JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with" +FROM + (VALUES + (jsonb '1'), + ('[]'), + ('[null]'), + ('[12.3]'), + ('[true]'), + ('["aaa"]'), + ('[[1, 2, 3]]'), + ('[{"a": 1, "b": [2]}]'), + ('[1, "2", null, [3]]') + ) foo(js); + +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text); +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES); +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING); +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES); +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING); +SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR); +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR); +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR); + +-- Behavior when a RETURNING type has typmod != -1 +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2)); +SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2) OMIT QUOTES); +SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bbb' ON EMPTY); +SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bbb"'::jsonb ON EMPTY); + +-- QUOTES behavior should not be specified when WITH WRAPPER used: +-- Should fail +SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES); +SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES); +SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES); +SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES); +-- Should succeed +SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES); +SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES); + +-- test QUOTES behavior. +SELECT JSON_QUERY(jsonb'{"rec": "{1,2,3}"}', '$.rec' returning int[] omit quotes); +SELECT JSON_QUERY(jsonb'{"rec": "{1,2,3}"}', '$.rec' returning int[] keep quotes); +SELECT JSON_QUERY(jsonb'{"rec": "{1,2,3}"}', '$.rec' returning int[] keep quotes error on error); +SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range omit quotes); +SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range keep quotes); +SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range keep quotes error on error); + +SELECT JSON_QUERY(jsonb '[]', '$[*]'); +SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY); +SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY); +SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY); +SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY); +SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY); +SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY); + +SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR); +SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR); +SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR); +SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR); +SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR); + +SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR); +SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR); + +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json); +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON); +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb); +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON); +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text); +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10)); +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3)); +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON); +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea); +SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON); + +SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR); +SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR); +SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR); +SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR); +SELECT JSON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR); +SELECT JSON_QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR); + +-- Coercion fails with quotes on +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int2 error on error); +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int4 error on error); +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int8 error on error); +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING bool error on error); +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING numeric error on error); +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING real error on error); +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING float8 error on error); +-- Fine with OMIT QUOTES +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int2 omit quotes error on error); +SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING float8 omit quotes error on error); + +-- RETUGNING pseudo-types not allowed +SELECT JSON_QUERY(jsonb '[3,4]', '$[*]' RETURNING anyarray EMPTY OBJECT ON ERROR); + +SELECT + x, y, + JSON_QUERY( + jsonb '[1,2,3,4,5,null]', + '$[*] ? (@ >= $x && @ <= $y)' + PASSING x AS x, y AS y + WITH CONDITIONAL WRAPPER + EMPTY ARRAY ON EMPTY + ) list +FROM + generate_series(0, 4) x, + generate_series(0, 4) y; + +-- record type returning with quotes behavior. +CREATE TYPE comp_abc AS (a text, b int, c timestamp); +SELECT JSON_QUERY(jsonb'{"rec": "(abc,42,01.02.2003)"}', '$.rec' returning comp_abc omit quotes); +SELECT JSON_QUERY(jsonb'{"rec": "(abc,42,01.02.2003)"}', '$.rec' returning comp_abc keep quotes); +SELECT JSON_QUERY(jsonb'{"rec": "(abc,42,01.02.2003)"}', '$.rec' returning comp_abc keep quotes error on error); +DROP TYPE comp_abc; + +-- Extension: record types returning +CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]); +CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]); + +SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}}, {"a": 2}]', '$[0]' RETURNING sqljsonb_rec); +SELECT JSON_QUERY(jsonb '[{"a": "a", "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}}, {"a": 2}]', '$[0]' RETURNING sqljsonb_rec ERROR ON ERROR); +SELECT JSON_QUERY(jsonb '[{"a": "a", "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}}, {"a": 2}]', '$[0]' RETURNING sqljsonb_rec); +SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa": [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa); +SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca); + +SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}}, {"a": 2}]', '$[0]' RETURNING jsonpath); +SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}}, {"a": 2}]', '$[0]' RETURNING jsonpath ERROR ON ERROR); + +-- Extension: array types returning +SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER); +SELECT JSON_QUERY(jsonb '[1,2,null,"a"]', '$[*]' RETURNING int[] WITH WRAPPER ERROR ON ERROR); +SELECT JSON_QUERY(jsonb '[1,2,null,"a"]', '$[*]' RETURNING int[] WITH WRAPPER); +SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[])); + +-- Extension: domain types returning +SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null); +SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null); +SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null ERROR ON ERROR); + +-- Test timestamptz passing and output +SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts); +SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json); +SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb); + +-- Test constraints + +CREATE TABLE test_jsonb_constraints ( + js text, + i int, + x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER) + CONSTRAINT test_jsonb_constraint1 + CHECK (js IS JSON) + CONSTRAINT test_jsonb_constraint2 + CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr)) + CONSTRAINT test_jsonb_constraint3 + CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT '12' ON EMPTY ERROR ON ERROR) > i) + CONSTRAINT test_jsonb_constraint4 + CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]') + CONSTRAINT test_jsonb_constraint5 + CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > 'a' COLLATE "C") +); + +\d test_jsonb_constraints + +SELECT check_clause +FROM information_schema.check_constraints +WHERE constraint_name LIKE 'test_jsonb_constraint%' +ORDER BY 1; + +SELECT pg_get_expr(adbin, adrelid) +FROM pg_attrdef +WHERE adrelid = 'test_jsonb_constraints'::regclass +ORDER BY 1; + +INSERT INTO test_jsonb_constraints VALUES ('', 1); +INSERT INTO test_jsonb_constraints VALUES ('1', 1); +INSERT INTO test_jsonb_constraints VALUES ('[]'); +INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1); +INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1); +INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1); +INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1); + +DROP TABLE test_jsonb_constraints; + +-- Test mutabilily of query functions +CREATE TABLE test_jsonb_mutability(js jsonb, b int); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.time()')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.date()')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.time_tz()')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.timestamp()')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.timestamp_tz()')); + +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.date() < $.time_tz())')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.date() < $.time())')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.time() < $.time())')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.time() < $.time_tz())')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp() < $.timestamp_tz())')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp_tz() < $.timestamp_tz())')); + +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.time() < $.datetime("HH:MI TZH"))')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.date() < $.datetime("HH:MI TZH"))')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp() < $.datetime("HH:MI TZH"))')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp() < $.datetime("HH:MI"))')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp_tz() < $.datetime("HH:MI TZH"))')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp_tz() < $.datetime("HH:MI"))')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.date() < $x' PASSING '12:34'::timetz AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.date() < $x' PASSING '1234'::int AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.timestamp(2) < $.timestamp(3))')); + +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))')); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x)); +CREATE INDEX ON test_jsonb_mutability (JSON_VALUE(js, '$' DEFAULT random()::int ON ERROR)); + +-- DEFAULT expression +CREATE OR REPLACE FUNCTION ret_setint() RETURNS SETOF integer AS +$$ +BEGIN + RETURN QUERY EXECUTE 'select 1 union all select 1'; +END; +$$ +LANGUAGE plpgsql IMMUTABLE; +SELECT JSON_QUERY(js, '$' RETURNING int DEFAULT ret_setint() ON ERROR) FROM test_jsonb_mutability; +SELECT JSON_QUERY(js, '$' RETURNING int DEFAULT b + 1 ON ERROR) FROM test_jsonb_mutability; +SELECT JSON_QUERY(js, '$' RETURNING int DEFAULT sum(1) over() ON ERROR) FROM test_jsonb_mutability; +SELECT JSON_QUERY(js, '$' RETURNING int DEFAULT (SELECT 1) ON ERROR) FROM test_jsonb_mutability; +DROP TABLE test_jsonb_mutability; +DROP FUNCTION ret_setint; + +-- Extension: non-constant JSON path +SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a'); +SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a'); +SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY); +SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a'); +SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER); +-- Should fail (invalid path) +SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error'); + +-- Non-jsonb inputs automatically coerced to jsonb +SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a'); +SELECT JSON_QUERY(NULL FORMAT JSON, '$'); + +-- Test non-const jsonpath +CREATE TEMP TABLE jsonpaths (path) AS SELECT '$'; +SELECT json_value('"aaa"', path RETURNING json) FROM jsonpaths; diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list index c79e7b2eb6..3b8cec58ab 100644 --- a/src/tools/pgindent/typedefs.list +++ b/src/tools/pgindent/typedefs.list @@ -1262,6 +1262,7 @@ Join JoinCostWorkspace JoinDomain JoinExpr +JsonFuncExpr JoinHashEntry JoinPath JoinPathExtraData @@ -1272,14 +1273,20 @@ JsObject JsValue JsonAggConstructor JsonAggState +JsonArgument JsonArrayAgg JsonArrayConstructor JsonArrayQueryConstructor JsonBaseObjectInfo +JsonBehavior +JsonBehaviorType JsonConstructorExpr JsonConstructorExprState JsonConstructorType JsonEncoding +JsonExpr +JsonExprOp +JsonExprState JsonFormat JsonFormatType JsonHashEntry @@ -1301,6 +1308,7 @@ JsonParseContext JsonParseErrorType JsonPath JsonPathBool +JsonPathDatatypeStatus JsonPathExecContext JsonPathExecResult JsonPathGinAddPathItemFunc @@ -1313,10 +1321,13 @@ JsonPathGinPathItem JsonPathItem JsonPathItemType JsonPathKeyword +JsonPathMutableContext JsonPathParseItem JsonPathParseResult JsonPathPredicateCallback JsonPathString +JsonPathVariable +JsonQuotes JsonReturning JsonScalarExpr JsonSemAction @@ -1333,6 +1344,7 @@ JsonValueExpr JsonValueList JsonValueListIterator JsonValueType +JsonWrapper Jsonb JsonbAggState JsonbContainer