diff --git a/src/common/backend/catalog/builtin_funcs.ini b/src/common/backend/catalog/builtin_funcs.ini index d45c97453..c42c42822 100644 --- a/src/common/backend/catalog/builtin_funcs.ini +++ b/src/common/backend/catalog/builtin_funcs.ini @@ -6263,6 +6263,10 @@ "json_each_text", 1, AddBuiltinFunc(_0(3259), _1("json_each_text"), _2(1), _3(true), _4(true), _5(json_each_text), _6(2249), _7(PG_CATALOG_NAMESPACE), _8(BOOTSTRAP_SUPERUSERID), _9(INTERNALlanguageId), _10(1), _11(100), _12(0), _13(0), _14(false), _15(false), _16(false), _17(false), _18('i'), _19(0), _20(1, 114), _21(3, 114, 25, 25), _22(3, 'i', 'o', 'o'), _23(3, "from_json", "key", "value"), _24(NULL), _25("json_each_text"), _26(NULL), _27(NULL), _28(NULL), _29(0), _30(false), _31(false), _32(false), _33(NULL), _34('f'), _35(NULL), _36(0), _37(false), _38(NULL), _39(NULL), _40(0)) ), + AddFuncGroup( + "json_exists", 1, + AddBuiltinFunc(_0(8810), _1("json_exists"), _2(3), _3(false), _4(false), _5(json_path_exists), _6(16), _7(PG_CATALOG_NAMESPACE), _8(BOOTSTRAP_SUPERUSERID), _9(INTERNALlanguageId), _10(1), _11(0), _12(0), _13(0), _14(false), _15(false), _16(false), _17(false), _18('i'), _19(0), _20(3, 25, 25, 21), _21(NULL), _22(NULL), _23(NULL), _24(NULL), _25("json_path_exists"), _26(NULL), _27(NULL), _28(NULL), _29(0), _30(false), _31(false), _32(false), _33(NULL), _34('f'), _35(NULL), _36(0), _37(false), _38(NULL), _39(NULL), _40(0)) + ), AddFuncGroup( "json_extract_path", 1, AddBuiltinFunc(_0(3262), _1("json_extract_path"), _2(2), _3(true), _4(false), _5(json_extract_path), _6(114), _7(PG_CATALOG_NAMESPACE), _8(BOOTSTRAP_SUPERUSERID), _9(INTERNALlanguageId), _10(1), _11(0), _12(25), _13(0), _14(false), _15(false), _16(false), _17(false), _18('i'), _19(0), _20(2, 114, 1009), _21(2, 114, 1009), _22(2, 'i', 'v'), _23(NULL), _24(NULL), _25("json_extract_path"), _26(NULL), _27(NULL), _28(NULL), _29(0), _30(false), _31(false), _32(false), _33(NULL), _34('f'), _35(NULL), _36(0), _37(false), _38(NULL), _39(NULL), _40(0)) @@ -6324,6 +6328,10 @@ "json_populate_recordset", 1, AddBuiltinFunc(_0(3409), _1("json_populate_recordset"), _2(3), _3(false), _4(true), _5(json_populate_recordset), _6(2283), _7(PG_CATALOG_NAMESPACE), _8(BOOTSTRAP_SUPERUSERID), _9(INTERNALlanguageId), _10(1), _11(100), _12(0), _13(0), _14(false), _15(false), _16(false), _17(false), _18('s'), _19(1), _20(3, 2283, 114, 16), _21(NULL), _22(NULL), _23(NULL), _24("({CONST :consttype 16 :consttypmod -1 :constcollid 0 :constlen 1 :constbyval true :constisnull false :ismaxvalue false :location 72803 :constvalue 1 [ 0 0 0 0 0 0 0 0 ] :cursor_data :row_count 0 :cur_dno 0 :is_open false :found false :not_found false :null_open false :null_fetch false})"), _25("json_populate_recordset"), _26(NULL), _27(NULL), _28(NULL), _29(1, 2), _30(false), _31(false), _32(false), _33(NULL), _34('f'), _35(NULL), _36(0), _37(false), _38(NULL), _39(NULL), _40(0)) ), + AddFuncGroup( + "json_textcontains", 1, + AddBuiltinFunc(_0(8811), _1("json_textcontains"), _2(3), _3(false), _4(false), _5(json_textcontains), _6(16), _7(PG_CATALOG_NAMESPACE), _8(BOOTSTRAP_SUPERUSERID), _9(INTERNALlanguageId), _10(1), _11(0), _12(0), _13(0), _14(false), _15(false), _16(false), _17(false), _18('i'), _19(0), _20(3, 25, 25, 2275), _21(NULL), _22(NULL), _23(NULL), _24(NULL), _25("json_textcontains"), _26(NULL), _27(NULL), _28(NULL), _29(0), _30(false), _31(false), _32(false), _33(NULL), _34('f'), _35(NULL), _36(0), _37(false), _38(NULL), _39(NULL), _40(0)) + ), AddFuncGroup( "json_to_record", 1, AddBuiltinFunc(_0(3410), _1("json_to_record"), _2(2), _3(false), _4(false), _5(json_to_record), _6(2249), _7(PG_CATALOG_NAMESPACE), _8(BOOTSTRAP_SUPERUSERID), _9(INTERNALlanguageId), _10(1), _11(0), _12(0), _13(0), _14(false), _15(false), _16(false), _17(false), _18('s'), _19(0), _20(2, 114, 16), _21(NULL), _22(NULL), _23(NULL), _24(NULL), _25("json_to_record"), _26(NULL), _27(NULL), _28(NULL), _29(0), _30(false), _31(false), _32(false), _33(NULL), _34('f'), _35(NULL), _36(0), _37(false), _38(NULL), _39(NULL), _40(0)) diff --git a/src/common/backend/parser/gram.y b/src/common/backend/parser/gram.y index 27f8c2455..953eda8e9 100644 --- a/src/common/backend/parser/gram.y +++ b/src/common/backend/parser/gram.y @@ -673,7 +673,7 @@ static char* IdentResolveToChar(char *ident, core_yyscan_t yyscanner); ExclusionWhereClause func_table_with_table %type ExclusionConstraintList ExclusionConstraintElem %type func_arg_list -%type func_arg_expr +%type func_arg_expr on_error_clause opt_on_error_clause %type row explicit_row implicit_row type_list array_expr_list %type case_expr case_arg when_clause case_default %type when_clause_list @@ -960,7 +960,7 @@ static char* IdentResolveToChar(char *ident, core_yyscan_t yyscanner); INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER INTERNAL INTERSECT INTERVAL INTO INVISIBLE INVOKER IP IS ISNULL ISOLATION - JOIN + JOIN JSON_EXISTS KEEP KEY KILL KEY_PATH KEY_STORE @@ -1046,6 +1046,7 @@ static char* IdentResolveToChar(char *ident, core_yyscan_t yyscanner); FORCE_INDEX USE_INDEX IGNORE_INDEX CURSOR_EXPR LATERAL_EXPR + FALSE_ON_ERROR TRUE_ON_ERROR ERROR_ON_ERROR /* Precedence: lowest to highest */ %nonassoc COMMENT @@ -29273,6 +29274,25 @@ func_application_special: func_name '(' ')' n->call_func = false; $$ = (Node *)n; } + | JSON_EXISTS '(' func_arg_list opt_on_error_clause ')' + { + FuncCall* n = makeNode(FuncCall); + Node* onError; + n->funcname = list_make1(makeString("json_exists")); + if ($4 == NULL) + onError = makeIntConst(0, @4); + else + onError = $4; + n->args = lappend($3, onError); + n->agg_order = NIL; + n->agg_star = FALSE; + n->agg_distinct = FALSE; + n->func_variadic = FALSE; + n->over = NULL; + n->location = @1; + n->call_func = FALSE; + $$ = (Node *)n; + } ; @@ -29288,6 +29308,13 @@ opt_default_nls_clause: } ; +opt_on_error_clause: /* EMPTY */ { $$ = NULL; } + | on_error_clause { $$ = $1; }; + +on_error_clause: ERROR_ON_ERROR { $$ = makeIntConst(2, @1); } + | TRUE_ON_ERROR { $$ = makeIntConst(1, @1); } + | FALSE_ON_ERROR { $$ = makeIntConst(0, @1); }; + /* * Function with SEPARATOR keword arguments; */ @@ -31980,6 +32007,7 @@ col_name_keyword: | INT_P | INTEGER | INTERVAL + | JSON_EXISTS | LEAST | NATIONAL | NCHAR diff --git a/src/common/backend/parser/parser.cpp b/src/common/backend/parser/parser.cpp index 277ff6e48..21f57fb04 100644 --- a/src/common/backend/parser/parser.cpp +++ b/src/common/backend/parser/parser.cpp @@ -898,6 +898,100 @@ int base_yylex(YYSTYPE* lvalp, YYLTYPE* llocp, core_yyscan_t yyscanner) break; } break; + case FALSE_P: + /* ERROR ON ERROR, TRUE ON ERROR and FALSE ON ERROR must be reduced to one token */ + GET_NEXT_TOKEN(); + core_yystype_1 = cur_yylval; + cur_yylloc_1 = cur_yylloc; + next_token_1 = next_token; + + switch (next_token) { + case ON: + GET_NEXT_TOKEN(); + core_yystype_2 = cur_yylval; + cur_yylloc_2 = cur_yylloc; + next_token_2 = next_token; + + switch (next_token) { + case ERROR_P: + cur_token = FALSE_ON_ERROR; + break; + default: + SET_LOOKAHEAD_2_TOKEN(); + break; + } + break; + default: + /* save the lookahead token for next time */ + SET_LOOKAHEAD_TOKEN(); + /* and back up the output info to cur_token */ + lvalp->core_yystype = cur_yylval; + *llocp = cur_yylloc; + break; + } + break; + case TRUE_P: + GET_NEXT_TOKEN(); + core_yystype_1 = cur_yylval; + cur_yylloc_1 = cur_yylloc; + next_token_1 = next_token; + + switch (next_token) { + case ON: + GET_NEXT_TOKEN(); + core_yystype_2 = cur_yylval; + cur_yylloc_2 = cur_yylloc; + next_token_2 = next_token; + + switch (next_token) { + case ERROR_P: + cur_token = TRUE_ON_ERROR; + break; + default: + SET_LOOKAHEAD_2_TOKEN(); + break; + } + break; + default: + /* save the lookahead token for next time */ + SET_LOOKAHEAD_TOKEN(); + /* and back up the output info to cur_token */ + lvalp->core_yystype = cur_yylval; + *llocp = cur_yylloc; + break; + } + break; + case ERROR_P: + GET_NEXT_TOKEN(); + core_yystype_1 = cur_yylval; + cur_yylloc_1 = cur_yylloc; + next_token_1 = next_token; + + switch (next_token) { + case ON: + GET_NEXT_TOKEN(); + core_yystype_2 = cur_yylval; + cur_yylloc_2 = cur_yylloc; + next_token_2 = next_token; + + switch (next_token) { + case ERROR_P: + cur_token = ERROR_ON_ERROR; + break; + default: + SET_LOOKAHEAD_2_TOKEN(); + break; + } + break; + default: + /* save the lookahead token for next time */ + SET_LOOKAHEAD_TOKEN(); + /* and back up the output info to cur_token */ + lvalp->core_yystype = cur_yylval; + *llocp = cur_yylloc; + break; + } + break; default: break; } diff --git a/src/common/backend/utils/adt/CMakeLists.txt b/src/common/backend/utils/adt/CMakeLists.txt index b33909070..fb58ad63d 100755 --- a/src/common/backend/utils/adt/CMakeLists.txt +++ b/src/common/backend/utils/adt/CMakeLists.txt @@ -1,9 +1,34 @@ #This is the main CMAKE for build all components. AUX_SOURCE_DIRECTORY(${CMAKE_CURRENT_SOURCE_DIR} TGT_adt_SRC) + +execute_process( + COMMAND bison -d -o jsonpath_gram.cpp jsonpath_gram.y + WORKING_DIRECTORY ${CMAKE_CURRENT_SOURCE_DIR} + OUTPUT_VARIABLE PARSER_GRAM +) +execute_process( + COMMAND sed -i "s/YY_NULL nullptr/YY_NULL 0/g" jsonpath_gram.cpp + WORKING_DIRECTORY ${CMAKE_CURRENT_SOURCE_DIR} + OUTPUT_VARIABLE PARSER_GRAM +) + +set(jsonpath_cmd_src +"${PROJECT_SRC_DIR}/common/backend/utils/adt|||flex -CF -b -p -p -o 'jsonpath_scan.inc' jsonpath_scan.l|sed -i 's/YY_NULL/YY_ZERO/g' scan.inc" +) + +add_cmd_gen_when_configure(flex_target jsonpath_cmd_src) + +execute_process( + COMMAND ln -fs ${CMAKE_CURRENT_SOURCE_DIR}/jsonpath_gram.hpp ${CMAKE_CURRENT_SOURCE_DIR}/../include/utils/jsonpath_gram.hpp +) + list(REMOVE_ITEM TGT_adt_SRC ${CMAKE_CURRENT_SOURCE_DIR}/like_match.cpp ) +list(APPEND TGT_adt_SRC + ${CMAKE_CURRENT_SOURCE_DIR}/jsonpath_gram.cpp) + set(TGT_adt_INC ${PROJECT_TRUNK_DIR}/distribute/include ${PROJECT_SRC_DIR}/include diff --git a/src/common/backend/utils/adt/Makefile b/src/common/backend/utils/adt/Makefile index 8875214f1..10dbedca3 100644 --- a/src/common/backend/utils/adt/Makefile +++ b/src/common/backend/utils/adt/Makefile @@ -27,7 +27,7 @@ OBJS = acl.o arrayfuncs.o array_selfuncs.o array_typanalyze.o \ cash.o char.o date.o datetime.o datum.o domains.o \ enum.o set.o float.o format_type.o \ geo_ops.o geo_selfuncs.o hotkey.o int.o int8.o int16.o \ - json.o jsonb.o jsonb_gin.o jsonb_op.o jsonb_util.o jsonfuncs.o like.o lockfuncs.o \ + json.o jsonb.o jsonb_gin.o jsonb_op.o jsonb_util.o jsonfuncs.o jsonpath.o jsonpath_gram.o like.o lockfuncs.o \ misc.o nabstime.o name.o numeric.o numutils.o \ oid.o a_compat.o orderedsetaggs.o pseudotypes.o rangetypes.o rangetypes_gist.o \ rowtypes.o regexp.o regproc.o ruleutils.o selfuncs.o \ @@ -44,4 +44,31 @@ OBJS = acl.o arrayfuncs.o array_selfuncs.o array_typanalyze.o \ like.o: like.cpp like_match.cpp +FLEXFLAGS = -CF -b -p -p + include $(top_srcdir)/src/gausskernel/common.mk + +jsonpath_gram.o: jsonpath_scan.inc + +# Latest flex causes warnings in this file. +ifeq ($(GCC),yes) +jsonpath_gram.o: CXXFLAGS += -Wno-error +endif + +jsonpath_gram.hpp: jsonpath_gram.cpp ; + +jsonpath_gram.cpp: jsonpath_gram.y +ifdef BISON + $(BISON) -d $(BISONFLAGS) -o $@ $< + sed -i 's/YY_NULL nullptr/YY_NULL 0/g' jsonpath_gram.cpp +else + @$(missing) bison $< $@ + sed -i 's/YY_NULL nullptr/YY_NULL 0/g' jsonpath_gram.cpp +endif + +jsonpath_scan.inc: jsonpath_scan.l +ifdef FLEX + $(FLEX) $(FLEXFLAGS) -o'$@' $< +else + @$(missing) flex $< $@ +endif diff --git a/src/common/backend/utils/adt/json.cpp b/src/common/backend/utils/adt/json.cpp index 4e3259729..bfdf331b8 100644 --- a/src/common/backend/utils/adt/json.cpp +++ b/src/common/backend/utils/adt/json.cpp @@ -2212,3 +2212,10 @@ Datum json_typeof(PG_FUNCTION_ARGS) PG_RETURN_TEXT_P(cstring_to_text(type)); } + +extern int json_typeof_internal(text* json) +{ + JsonLexContext *lex = makeJsonLexContext(json, false); + json_lex(lex); + return lex_peek(lex); +} \ No newline at end of file diff --git a/src/common/backend/utils/adt/jsonfuncs.cpp b/src/common/backend/utils/adt/jsonfuncs.cpp index 60a206bbd..8f0d9bedb 100644 --- a/src/common/backend/utils/adt/jsonfuncs.cpp +++ b/src/common/backend/utils/adt/jsonfuncs.cpp @@ -34,6 +34,7 @@ #include "utils/memutils.h" #include "utils/typcache.h" #include "utils/array.h" +#include "utils/jsonpath.h" /* Operations available for setPath */ #define JB_PATH_CREATE 0x0001 @@ -125,6 +126,12 @@ static void setPathObject(JsonbIterator **it, Datum *path_elems, bool *path_null static void setPathArray(JsonbIterator **it, Datum *path_elems, bool *path_nulls, int path_len, JsonbParseState **st, int level, Jsonb *newval, int nelems, int op_type); +/* semantic action functions for get json object values */ +static void OvalsArrayStart(void* stateIn); +static void OvalsScalar(void* stateIn, char* token, JsonTokenType tokentype); +static void OvalsObjectFieldStart(void* stateIn, char* fname, bool isnull); +static void OvalsObjectFieldEnd(void* stateIn, char* fname, bool isnull); + /* search type classification for json_get* functions */ typedef enum { JSON_SEARCH_OBJECT = 1, @@ -132,6 +139,12 @@ typedef enum { JSON_SEARCH_PATH } JsonSearch; +typedef enum { + FALSE_ON_ERROR = 0, /* default */ + TRUE_ON_ERROR, + ERROR_ON_ERROR +} OnErrorType; + /* state for json_object_keys */ typedef struct OkeysState { JsonLexContext *lex; @@ -238,9 +251,50 @@ typedef struct PopulateRecordsetState { MemoryContext fn_mcxt; /* used to stash IO funcs */ } PopulateRecordsetState; +struct OvalsState { + JsonLexContext* lex; + char **result; + int result_size; + int result_count; + char* result_start; +}; + +struct JsonExistsPathContext { + bool result; +}; + +struct JsonTextContainsContext { + char* target; + bool result; +}; + +struct JsonStringArray { + char** data; + int len; + int maxlen; +}; + /* Turn a jsonb object into a record */ static void make_row_from_rec_and_jsonb(Jsonb *element, PopulateRecordsetState *state); +/* functions supporting json_exists and json_textcontains */ +static bool IsJsonText(text* t); +static void JsonPathWalker(JsonPathItem* path, text* topJson, text* json, void (*pwalker)(text*, void*), void* context); +static void JPWalkArrayStep(JsonPathItem* path, text* topJson, text* json, + void (*pwalker)(text*, void*), void* context); +static void JPWalkObjectStep(JsonPathItem* path, text* topJson, text* json, + void (*pwalker)(text*, void*), void* context); +static OvalsState* json_object_values_internal(text* json); + +/* functions supporting json_exists */ +static void JsonPathExistsPathWalker(text* json, JsonExistsPathContext* context); + +/* functions supporting json_textcontains */ +static List* GetObjectValues(text* json); +static void SplitString(char* str, char delim, int strlen, JsonStringArray* results); +static void CollectValsFromJson(text* json, JsonStringArray* vals); +static void JsonTextContainsWalker(text* json, JsonTextContainsContext* context); + /* * SQL function json_object_keys * @@ -3332,3 +3386,436 @@ Datum jsonb_set(PG_FUNCTION_ARGS) PG_RETURN_JSONB(JsonbValueToJsonb(res)); } + +static void OvalsArrayStart(void* stateIn) +{ + OvalsState* state = (OvalsState *)stateIn; + + /* top level must be a json object */ + if (state->lex->lex_level == 0) { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("cannot get object values from an array"))); + } +} + +static void OvalsScalar(void* stateIn, char* token, JsonTokenType tokentype) +{ + OvalsState* state = (OvalsState*)stateIn; + + /* json structure check */ + if (state->lex->lex_level == 0) { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("cannot get object values from a scalar"))); + } +} + +static void OvalsObjectFieldStart(void* stateIn, char* fname, bool isnull) +{ + OvalsState* state = (OvalsState*) stateIn; + + /* save a pointer to where the value starts */ + if (state->lex->lex_level == 1) { + state->result_start = state->lex->token_start; + } +} + +static void OvalsObjectFieldEnd(void* stateIn, char* fname, bool isnull) +{ + OvalsState* state = (OvalsState*) stateIn; + + /* skip over nested objects */ + if (state->lex->lex_level != 1) { + return; + } + + if (state->result_count >= state->result_size) { + int doubleSize = 2; + state->result_size *= doubleSize; + state->result = static_cast(repalloc(state->result, sizeof(char *) * state->result_size)); + } + + int len = state->lex->prev_token_terminator - state->result_start + 1; + if (len > 0) { + char* result = static_cast(palloc(len * sizeof(char))); + int rc = memcpy_s(result, len, state->result_start, len); + securec_check(rc, "\0", "\0"); + result[len - 1] = '\0'; + state->result[state->result_count++] = result; + } else { + state->result[state->result_count++] = NULL; + } +} + +static OvalsState* json_object_values_internal(text* json) +{ + OvalsState* state = NULL; + JsonLexContext* lex = makeJsonLexContext(json, true); + JsonSemAction* sem = NULL; + int initSize = 256; + + state = static_cast(palloc(sizeof(OvalsState))); + sem = static_cast(palloc0(sizeof(JsonSemAction))); + + state->lex = lex; + state->result_size = initSize; + state->result_count = 0; + state->result = static_cast(palloc(initSize * sizeof(char*))); + + sem->semstate = (void*)state; + sem->array_start = OvalsArrayStart; + sem->scalar = OvalsScalar; + sem->object_field_start = OvalsObjectFieldStart; + sem->object_field_end = OvalsObjectFieldEnd; + + pg_parse_json(lex, sem); + + pfree(lex->strval->data); + pfree(lex->strval); + pfree(lex); + + return state; +} + +static bool IsJsonText(text* t) +{ + JsonLexContext* lex = makeJsonLexContext(t, false); + MemoryContext oldcxt = CurrentMemoryContext; + bool result = false; + JsonSemAction nullSemAction = { + NULL, NULL, NULL, NULL, NULL, + NULL, NULL, NULL, NULL, NULL + }; + + PG_TRY(); + { + /* try to parse the text as a formatted json, + if this fails, the text is not a formatted json */ + pg_parse_json(lex, &nullSemAction); + result = true; + } + PG_CATCH(); + { + ErrorData* edata = &t_thrd.log_cxt.errordata[t_thrd.log_cxt.errordata_stack_depth]; + if (edata->sqlerrcode == ERRCODE_INVALID_TEXT_REPRESENTATION) { + MemoryContextSwitchTo(oldcxt); + result = false; + FlushErrorState(); + } else { + PG_RE_THROW(); + } + } + PG_END_TRY(); + + return result; +} + +static List* GetObjectValues(text* json) +{ + OvalsState* state = json_object_values_internal(json); + List* resultList = NIL; + + for (int i = 0; i < state->result_count; i++) { + resultList = lappend(resultList, cstring_to_text(state->result[i])); + pfree(state->result[i]); + } + pfree(state->result); + pfree(state); + + return resultList; +} + +static void JPWalkArrayStep(JsonPathItem* path, text* topJson, text* json, + void (*pwalker)(text*, void*), void* context) +{ + JsonPathArrayStep* as = (JsonPathArrayStep*)path; + char* jsonType = text_to_cstring(DatumGetTextP(DirectFunctionCall1(json_typeof, PointerGetDatum(json)))); + text* result = NULL; + if (strcmp(jsonType, "array") != 0) + return; + + if (as->indexes != NIL) { + ListCell* idxCell = NULL; + int index; + + foreach (idxCell, as->indexes) { + int index = lfirst_int(idxCell); + result = get_worker(json, NULL, index, NULL, NULL, -1, true); + JsonPathWalker(path->next, topJson, result, pwalker, context); + } + } else { + int length = DatumGetInt32(DirectFunctionCall1(json_array_length, PointerGetDatum(json))); + for (int i = 0; i < length; i++) { + result = get_worker(json, NULL, i, NULL, NULL, -1, true); + JsonPathWalker(path->next, topJson, result, pwalker, context); + } + } +} + +static void JPWalkObjectStep(JsonPathItem* path, text* topJson, text* json, + void (*pwalker)(text*, void*), void* context) +{ + JsonPathObjectStep* os = (JsonPathObjectStep*)path; + char* jsonType = text_to_cstring(DatumGetTextP(DirectFunctionCall1(json_typeof, PointerGetDatum(json)))); + text* result = NULL; + if (strcmp(jsonType, "object") != 0) + return; + + if (os->fieldName != NULL) { + result = get_worker(json, os->fieldName, -1, NULL, NULL, -1, true); + JsonPathWalker(path->next, topJson, result, pwalker, context); + } else { + List* valList = GetObjectValues(json); + ListCell* valCell = NULL; + + foreach(valCell, valList) { + text* valTxt = (text*)lfirst(valCell); + JsonPathWalker(path->next, topJson, valTxt, pwalker, context); + } + } +} + +static void JsonPathWalker(JsonPathItem* path, text* topJson, text* json, void (*pwalker)(text*, void*), void* context) +{ + if (path == NULL) { + pwalker(json, context); + return; + } else if (json == NULL || !IsJsonText(json)) { + return; + } + + check_stack_depth(); + + switch (path->type) { + case JPI_ABSOLUTE_START: + JsonPathWalker(path->next, topJson, topJson, pwalker, context); + break; + case JPI_ARRAY: { + JPWalkArrayStep(path, topJson, json, pwalker, context); + break; + } + case JPI_OBJECT: { + JPWalkObjectStep(path, topJson, json, pwalker, context); + break; + } + default: + ereport(ERROR, + (errcode(ERRCODE_UNRECOGNIZED_NODE_TYPE), + errmsg("unrecognized json path item type: %d", path->type))); + } +} + +static void JsonPathExistsPathWalker(text* json, JsonExistsPathContext* context) +{ + if (context->result) + return; + + context->result = !(json == NULL); +} + +/* + * SQL function json_exists + * returns true if there's data in json under specified pathStr + */ +Datum json_path_exists(PG_FUNCTION_ARGS) +{ + if (PG_ARGISNULL(1)) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("the json path expression is not of text type"))); + + int argnum = 2; + + if (PG_ARGISNULL(0) || PG_ARGISNULL(argnum)) + PG_RETURN_NULL(); + + text* json = PG_GETARG_TEXT_P(0); + const char* pathStr = text_to_cstring(PG_GETARG_TEXT_P(1)); + OnErrorType onError = (OnErrorType)PG_GETARG_INT32(2); + int len = strlen(pathStr); + JsonPathItem* path = ParseJsonPath(pathStr, len); + + JsonExistsPathContext context; + if (!IsJsonText(json)) + switch (onError) { + case FALSE_ON_ERROR: + context.result = false; + break; + case TRUE_ON_ERROR: + context.result = true; + break; + case ERROR_ON_ERROR: + ereport(ERROR, + (errcode(ERRCODE_INVALID_TEXT_REPRESENTATION), + errmsg("the input is not a well-formed json data"))); + break; + default: + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("unrecognized ON ERROR option: %d", onError))); + break; + } else { + context.result = false; + JsonPathWalker(path, json, json, (void (*)(text*, void*))JsonPathExistsPathWalker, (void*)(&context)); + } + + PG_RETURN_BOOL(context.result); +} + +static void ExpandJsonStringArray(JsonStringArray* array) +{ + if (array->len >= array->maxlen) { + int doubleSize = 2; + array->maxlen *= doubleSize; + array->data = static_cast(repalloc(array->data, array->maxlen * sizeof(char*))); + } +} + +static void SplitString(char* str, char delim, int strlen, JsonStringArray* results) +{ + char* lptr = str; + char* rptr = str; + + while (*rptr != '\0' && strlen != 0) { + if (*rptr == delim || strlen == 1) { + if (rptr != lptr) { + ExpandJsonStringArray(results); + int len = (*rptr == delim) ? (rptr - lptr + 1) : (rptr - lptr + 2); + char* res = (char*)palloc(len * sizeof(char)); + int rc = memcpy_s(res, len, lptr, len); + securec_check(rc, "\0", "\0"); + res[len - 1] = '\0'; + results->data[results->len++] = res; + } + lptr = rptr + 1; + } + strlen--; + rptr++; + } +} + +static void CollectValsFromJson(text* json, JsonStringArray* vals) +{ + JsonTokenType tok = (JsonTokenType)json_typeof_internal(json); + + check_stack_depth(); + + switch (tok) { + case JSON_TOKEN_NULL: + return; + case JSON_TOKEN_NUMBER: + case JSON_TOKEN_TRUE: + case JSON_TOKEN_FALSE: + vals->data[vals->len++] = text_to_cstring(json); + break; + case JSON_TOKEN_STRING: { + char* cjson = text_to_cstring(json); + /* trim the quote mark before and after the string */ + int quotes = 2; + SplitString(cjson + 1, ' ', strlen(cjson) - quotes, vals); + break; + } + case JSON_TOKEN_OBJECT_START: { + List* valList = GetObjectValues(json); + ListCell* valCell = NULL; + + foreach(valCell, valList) { + text* valTxt = (text*)lfirst(valCell); + CollectValsFromJson(valTxt, vals); + } + break; + } + case JSON_TOKEN_ARRAY_START: { + int length = DatumGetInt32(DirectFunctionCall1(json_array_length, PointerGetDatum(json))); + text* result; + for (int i = 0; i < length; i++) { + result = get_worker(json, NULL, i, NULL, NULL, -1, true); + CollectValsFromJson(result, vals); + } + break; + } + default: + elog(ERROR, "unexpected json token: %d", tok); + } +} + +static void JsonTextContainsWalker(text* json, JsonTextContainsContext* context) +{ + if (context->result) + return; + + MemoryContext tmp_cxt = AllocSetContextCreate(CurrentMemoryContext, + "json_textcontains temp context", + ALLOCSET_DEFAULT_MINSIZE, + ALLOCSET_DEFAULT_INITSIZE, + ALLOCSET_DEFAULT_MAXSIZE); + MemoryContext old_cxt = MemoryContextSwitchTo(tmp_cxt); + JsonStringArray* targets = (JsonStringArray*)palloc(sizeof(JsonStringArray)); + JsonStringArray* vals = (JsonStringArray*)palloc(sizeof(JsonStringArray)); + int initLen = 256; + + targets->maxlen = initLen; + targets->len = 0; + targets->data = static_cast(palloc(targets->maxlen * sizeof(char*))); + vals->maxlen = initLen; + vals->len = 0; + vals->data = static_cast(palloc(targets->maxlen * sizeof(char*))); + + SplitString(context->target, ' ', strlen(context->target), targets); + CollectValsFromJson(json, vals); + + MemoryContextSwitchTo(old_cxt); + + int i, j; + for (i = 0; i <= (vals->len - targets->len); i++) { + for (j = 0; j < targets->len; j++) { + if (pg_strcasecmp(targets->data[j], vals->data[i + j]) != 0) + break; + } + if (j >= targets->len) { + context->result = true; + break; + } + } + + MemoryContextDelete(tmp_cxt); +} + +/* + * SQL function json_textcontains + * returns true if the json contains target under specified pathStr + */ + +Datum json_textcontains(PG_FUNCTION_ARGS) +{ + if (PG_ARGISNULL(1)) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("the json path expression is not of text type"))); + + int argnum = 2; + if (PG_ARGISNULL(0) || PG_ARGISNULL(argnum)) + PG_RETURN_NULL(); + + text* json = PG_GETARG_TEXT_P(0); + const char* pathStr = text_to_cstring(PG_GETARG_TEXT_P(1)); + int len = strlen(pathStr); + JsonPathItem* path = ParseJsonPath(pathStr, len); + char* target = PG_GETARG_CSTRING(2); + char* tok; + + JsonTextContainsContext context; + context.result = false; + + if (!IsJsonText(json)) + PG_RETURN_BOOL(context.result); + + tok = strtok(target, ","); + while (!(context.result) && tok != NULL) { + context.target = tok; + JsonPathWalker(path, json, json, (void (*)(text*, void*))JsonTextContainsWalker, (void*)(&context)); + tok = strtok(NULL, ","); + } + PG_RETURN_BOOL(context.result); +} \ No newline at end of file diff --git a/src/common/backend/utils/adt/jsonpath.cpp b/src/common/backend/utils/adt/jsonpath.cpp new file mode 100644 index 000000000..7b340e408 --- /dev/null +++ b/src/common/backend/utils/adt/jsonpath.cpp @@ -0,0 +1,101 @@ +/* + * Copyright (c) 2020 Huawei Technologies Co.,Ltd. + * Portions Copyright (c) 2021, openGauss Contributors + * + * openGauss is licensed under Mulan PSL v2. + * You can use this software according to the terms and conditions of the Mulan PSL v2. + * You may obtain a copy of Mulan PSL v2 at: + * + * http://license.coscl.org.cn/MulanPSL2 + * + * THIS SOFTWARE IS PROVIDED ON AN "AS IS" BASIS, WITHOUT WARRANTIES OF ANY KIND, + * EITHER EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO NON-INFRINGEMENT, + * MERCHANTABILITY OR FIT FOR A PARTICULAR PURPOSE. + * See the Mulan PSL v2 for more details. + * ------------------------------------------------------------------------- + * + * jsonpath.cpp + * + * IDENTIFICATION + * src/common/backend/utils/adt/jsonpath.cpp + * + * ------------------------------------------------------------------------- + */ + +#include "postgres.h" +#include "utils/json.h" +#include "utils/jsonapi.h" +#include "utils/jsonpath.h" + +/* + * The helper functions below allocate and fill JsonPathParseItem's of various + * types. + */ + +static bool IsJsonText(text* t); +static JsonPathItem* MakeItemBasic(JsonPathItemType type); +static JsonPathItem* MakeItemArrayStep(); +static JsonPathItem* MakeItemObjectStep(); + +JsonPathItem* MakeItemType(JsonPathItemType type) +{ + JsonPathItem* v = NULL; + switch (type) { + case JPI_NULL: + case JPI_ABSOLUTE_START: + v = MakeItemBasic(type); + break; + case JPI_ARRAY: + v = MakeItemArrayStep(); + break; + case JPI_OBJECT: + v = MakeItemObjectStep(); + break; + default: + ereport(ERROR, + (errcode(ERRCODE_UNRECOGNIZED_NODE_TYPE), + errmsg("unrecognized json path item type: %d", type))); + } + return v; +} + +JsonPathItem* MakeItemBasic(JsonPathItemType type) +{ + JsonPathItem* v = (JsonPathItem*)palloc(sizeof(JsonPathItem)); + + v->type = type; + v->next = NULL; + + return v; +} +JsonPathItem* MakeItemArrayStep() +{ + JsonPathArrayStep* v = (JsonPathArrayStep*)palloc(sizeof(JsonPathArrayStep)); + + v->type = JPI_ARRAY; + v->next = NULL; + v->indexes = NIL; + + return (JsonPathItem*)v; +} + +JsonPathItem* MakeItemObjectStep() +{ + JsonPathObjectStep* v = (JsonPathObjectStep*)palloc(sizeof(JsonPathObjectStep)); + + v->type = JPI_OBJECT; + v->next = NULL; + v->fieldName = NULL; + + return (JsonPathItem*)v; +} + +JsonPathParseItem* MakePathParseItem() +{ + JsonPathParseItem* v = (JsonPathParseItem*)palloc(sizeof(JsonPathParseItem)); + + v->head = NULL; + v->tail = NULL; + + return (JsonPathParseItem*)v; +} \ No newline at end of file diff --git a/src/common/backend/utils/adt/jsonpath_gram.y b/src/common/backend/utils/adt/jsonpath_gram.y new file mode 100644 index 000000000..1e4172a66 --- /dev/null +++ b/src/common/backend/utils/adt/jsonpath_gram.y @@ -0,0 +1,256 @@ +%{ +/* + * Copyright (c) 2020 Huawei Technologies Co.,Ltd. + * Portions Copyright (c) 2021, openGauss Contributors + * + * openGauss is licensed under Mulan PSL v2. + * You can use this software according to the terms and conditions of the Mulan PSL v2. + * You may obtain a copy of Mulan PSL v2 at: + * + * http://license.coscl.org.cn/MulanPSL2 + * + * THIS SOFTWARE IS PROVIDED ON AN "AS IS" BASIS, WITHOUT WARRANTIES OF ANY KIND, + * EITHER EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO NON-INFRINGEMENT, + * MERCHANTABILITY OR FIT FOR A PARTICULAR PURPOSE. + * See the Mulan PSL v2 for more details. + * ------------------------------------------------------------------------- + * + * jsonpath_gram.y + * + * IDENTIFICATION + * src/common/backend/utils/adt/jsonpath_gram.y + * + * ------------------------------------------------------------------------- + */ + +#include "postgres.h" +#include "utils/jsonpath.h" +#include "nodes/pg_list.h" +#include "regex/regex.h" +#include "parser/scanner.h" + + +/* Location tracking support --- simpler than bison's default */ + +#define YYLLOC_DEFAULT(Current, Rhs, N) \ + do { \ + if (N) \ + (Current) = (Rhs)[1]; \ + else \ + (Current) = (Rhs)[0]; \ + } while (0) + +#define YYLTYPE int +extern int jsonpath_yylex(YYSTYPE* lvalp, YYLTYPE* llocp); +#define YYMALLOC palloc +#define YYFREE pfree + +static void jsonpath_yyerror(const char *msg); +#define yyerror(yylloc, result, msg) jsonpath_yyerror(msg) + +%} + +/* BISON Declarations */ +%define api.pure +%expect 0 +%name-prefix="jsonpath_yy" +%locations + +%parse-param {JsonPathItem **result} + +%union +{ + JsonPathItem* value; + JsonPathParseItem* parse; + char* str; + bool boolean; + int integer; + List* list; +} + +%token IDENT_P NUMERIC_P STRING_P +%token INT_P +%token TO_P +%token ABS_P BOOLEAN_P CEILING_P DATE_P DOUBLE_P FLOOR_P + +%type basic_path absolute_path //relative_path + object_step array_step filter_expr opt_filter_expr function_steps +%type non_function_steps +%type fieldName +%type index +%type index_list array_index + +/* Grammar follows */ +%% +basic_path: + absolute_path { $$ = $1; }; + //relative_path { $$ = $1; }; + +absolute_path: '$' + { + *result = MakeItemType(JPI_ABSOLUTE_START); + } + | '$' non_function_steps + { + JsonPathItem* item = MakeItemType(JPI_ABSOLUTE_START); + + item->next = $2->head; + + *result = item; + } + | '$' function_steps + { + JsonPathItem* item = MakeItemType(JPI_ABSOLUTE_START); + + item->next = $2; + + $$ = item; + } + | '$' non_function_steps function_steps + { + JsonPathItem* item = MakeItemType(JPI_ABSOLUTE_START); + + item->next = $2->head; + $2->tail->next = $3; + + $$ = item; + } + ; + +non_function_steps: object_step opt_filter_expr + { + JsonPathParseItem* item = MakePathParseItem(); + + item->head = $1; + item->tail = $2 == NULL ? $1 : $2; + $1->next = $2; + + $$ = item; + } + | non_function_steps object_step opt_filter_expr + { + $2->next = $3; + $1->tail->next = $2; + $1->tail = $3 == NULL ? $2 : $3; + } + | array_step opt_filter_expr + { + JsonPathParseItem* item = MakePathParseItem(); + + item->head = $1; + item->tail = $2 == NULL ? $1 : $2; + $1->next = $2; + + $$ = item; + } + | non_function_steps array_step opt_filter_expr + { + JsonPathParseItem* item = $1; + + item->tail->next = $2 != NULL ? $2 : $3; + item->tail = $3 != NULL ? $3 : + $2 != NULL ? $2 : $1->tail; + if ($2 != NULL) + $2->next = $3; + + $$ = item; + } + ; + +opt_filter_expr: filter_expr { $$ = $1; } + | /* EMPTY */ { $$ = NULL; }; + +filter_expr: '?' { $$ = NULL; }; + +array_step: '[' '*' ']' + { + $$ = MakeItemType(JPI_ARRAY); + } + | '[' index_list ']' + { + JsonPathItem* v = MakeItemType(JPI_ARRAY); + ((JsonPathArrayStep*)v)->indexes = $2; + $$ = v; + } + +index_list: array_index { $$ = $1; } + | index_list ',' array_index { $$ = list_concat($1, $3); }; + +array_index: index + { + $$ = list_make1_int($1); + } + | index TO_P index + { + int max = $3 > $1 ? $3 : $1; + int min = $3 > $1 ? $1 : $3; + List* l = list_make1_int(min); + + if (max < 0 || min < 0) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("array index cannot be negative"))); + + for (int i = min + 1; i <= max; i++) { + l = lappend_int(l, i); + } + + $$ = l; + } + ; + +index: INT_P + { + if ($1 < 0) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("array index cannot be negative"))); + + $$ = $1; + } + ; + +object_step: '.' '*' + { + $$ = MakeItemType(JPI_OBJECT); + } + | '.' fieldName + { + JsonPathItem* v = MakeItemType(JPI_OBJECT); + ((JsonPathObjectStep*)v)->fieldName = $2; + $$ = v; + } + ; +fieldName: IDENT_P { $$ = $1; }; + +function_steps: '.' method '(' ')' + { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("using methods in json path is not supported yet."))); + } + ; + +method: + ABS_P + | BOOLEAN_P + | CEILING_P + | DATE_P + | DOUBLE_P + | FLOOR_P +%% + +static void +jsonpath_yyerror(const char *msg) +{ + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("%s in json path expression", _(msg)))); +} + +#undef yyerror +#undef yylval +#undef yylloc +#undef yylex + +#include "jsonpath_scan.inc" diff --git a/src/common/backend/utils/adt/jsonpath_scan.l b/src/common/backend/utils/adt/jsonpath_scan.l new file mode 100644 index 000000000..fe84d3759 --- /dev/null +++ b/src/common/backend/utils/adt/jsonpath_scan.l @@ -0,0 +1,395 @@ +%{ +/*------------------------------------------------------------------------- + * + * jsonpath_scan.l + * Lexical parser for jsonpath datatype + * + * Splits jsonpath string into tokens represented as JsonPathString structs. + * Decodes unicode and hex escaped strings. + * + * Copyright (c) 2019-2024, PostgreSQL Global Development Group + * + * IDENTIFICATION + * src/backend/utils/adt/jsonpath_scan.l + * + *------------------------------------------------------------------------- + */ + +#include "postgres.h" +#include "knl/knl_variable.h" + +/* + * NB: include jsonpath_gram.h only AFTER including jsonpath_internal.h, + * because jsonpath_internal.h contains the declaration for JsonPathString. + */ +#include "utils/jsonpath.h" + +#include "mb/pg_wchar.h" + +#include "nodes/pg_list.h" +#include "utils/pl_package.h" +#include "utils/plpgsql.h" + +/* Avoid exit() on fatal scanner errors (a bit ugly -- see yy_fatal_error) */ +#undef fprintf +#define fprintf(file, fmt, msg) fprintf_to_ereport(fmt, msg) + +#define YY_DECL int jsonpath_yylex \ + (YYSTYPE * yylval_param, YYLTYPE * yylloc_param) +#define SET_YYLLOC() (*(yylloc)) + +static StringInfoData scanstring; +static yy_buffer_state* scanbufhandle; +static char* scanbuf; + +static void addstring(bool init, char *s, int l); +static void addchar(bool init, char c); +static enum yytokentype checkKeyword(void); +static int process_integer_literal(const char *token, YYSTYPE *lval); +static void +fprintf_to_ereport(const char *fmt, const char *msg) +{ + ereport(ERROR, (errmsg_internal("%s", msg))); +} + +/* LCOV_EXCL_START */ + +%} + +%option 8bit +%option never-interactive +%option nodefault +%option noinput +%option nounput +%option noyywrap +%option warn +%option prefix="jsonpath_yy" +%option bison-bridge +%option noyyalloc +%option noyyrealloc +%option noyyfree + + +/* + * We use exclusive states for quoted and non-quoted strings, + * quoted variable names and C-style comments. + * Exclusive states: + * - quoted strings + */ +%x xq +%x xnq +%x xvq + +special [\?\%\$\.\[\]\{\}\(\)\|\&\!\=\<\>\@\#\,\*:\-\+\/] +blank [ \t\n\r\f] +/* "other" means anything that's not special, blank, or '\' or '"' */ +other [^\?\%\$\.\[\]\{\}\(\)\|\&\!\=\<\>\@\#\,\*:\-\+\/\\\" \t\n\r\f] + +digit [0-9] + +/* DecimalInteger in ECMAScript; must not start with 0 unless it's exactly 0 */ +integer (0|[1-9](_?{digit})*) +/* DecimalDigits in ECMAScript; only used as part of other rules */ +digits {digit}(_?{digit})* + +decimal ({integer}\.{digits}?|\.{digits}) +real ({integer}|{decimal})[Ee][-+]?{digits} +realfail ({integer}|{decimal})[Ee][-+] + +integer_junk {integer}{other} +decimal_junk {decimal}{other} +real_junk {real}{other} + +%% +{other}+ { + addstring(false, yytext, yyleng); + } + +{blank}+ { + yylval->str = scanstring.data; + BEGIN INITIAL; + return checkKeyword(); + } + +({special}|\") { + yylval->str = scanstring.data; + yyless(0); + BEGIN INITIAL; + return checkKeyword(); + } + +<> { + yylval->str = scanstring.data; + BEGIN INITIAL; + return checkKeyword(); + } + +\\b { addchar(false, '\b'); } + +\\f { addchar(false, '\f'); } + +\\n { addchar(false, '\n'); } + +\\r { addchar(false, '\r'); } + +\\t { addchar(false, '\t'); } + +\\v { addchar(false, '\v'); } + +\\. { addchar(false, yytext[1]); } + +\\ { + jsonpath_yyerror("unexpected end after backslash"); + yyterminate(); + } + +<> { + jsonpath_yyerror("unterminated quoted string"); + yyterminate(); + } + +\" { + yylval->str = scanstring.data; + BEGIN INITIAL; + return STRING_P; + } + +{special} { return *yytext; } + +{blank}+ { /* ignore */ } + +{real} { + addstring(true, yytext, yyleng); + addchar(false, '\0'); + yylval->str = scanstring.data; + return NUMERIC_P; + } + +{decimal} { + addstring(true, yytext, yyleng); + addchar(false, '\0'); + yylval->str = scanstring.data; + return NUMERIC_P; + } + +{integer} { + return process_integer_literal(yytext, yylval); + } + +{realfail} { + jsonpath_yyerror("invalid numeric literal"); + yyterminate(); + } +{integer_junk} { + jsonpath_yyerror("trailing junk after numeric literal"); + yyterminate(); + } +{decimal_junk} { + jsonpath_yyerror("trailing junk after numeric literal"); + yyterminate(); + } +{real_junk} { + jsonpath_yyerror("trailing junk after numeric literal"); + yyterminate(); + } +\" { + addchar(true, '\0'); + BEGIN xq; + } + +\\ { + yyless(0); + addchar(true, '\0'); + BEGIN xnq; + } + +{other}+ { + addstring(true, yytext, yyleng); + BEGIN xnq; + } + +<> { + yyterminate(); + } + +%% + +/* LCOV_EXCL_STOP */ + +/* + * Called before any actual parsing is done + */ +static void +jsonpath_scanner_init(const char *str, int slen) +{ + if (slen <= 0) + slen = strlen(str); + + /* + * Might be left over after ereport() + */ + yy_init_globals(); + + /* + * Make a scan buffer with special termination needed by flex. + */ + + scanbuf = (char*)palloc(slen + 2); + memcpy(scanbuf, str, slen); + scanbuf[slen] = scanbuf[slen + 1] = YY_END_OF_BUFFER_CHAR; + scanbufhandle = yy_scan_buffer(scanbuf, slen + 2); + + BEGIN(INITIAL); +} + +/* + * Called after parsing is done to clean up after jsonpath_scanner_init() + */ +static void +jsonpath_scanner_finish(void) +{ + yy_delete_buffer(scanbufhandle); + pfree(scanbuf); +} + +/* Add set of bytes at "s" of length "l" to scanstring */ +static void addstring(bool init, char *s, int l) +{ + if (init) { + initStringInfo(&scanstring); + } + appendStringInfo(&scanstring, "%s", s); +} + +/* Add single byte "c" to scanstring */ +static void addchar(bool init, char c) +{ + if (init) { + initStringInfo(&scanstring); + } + enlargeStringInfo(&scanstring, 1); + scanstring.data[scanstring.len] = c; + if (c != '\0') + scanstring.len++; +} + +typedef struct JsonPathKeyword +{ + int16 len; + bool lowercase; + int val; + const char *keyword; +} JsonPathKeyword; + +static const JsonPathKeyword keywords[] = { + { 2, false, TO_P, "to"}, + { 3, false, ABS_P, "abs"}, + { 4, false, DATE_P, "date"}, + { 5, false, FLOOR_P, "floor"}, + { 6, false, DOUBLE_P, "double"}, + { 7, false, BOOLEAN_P, "boolean"}, + { 7, false, CEILING_P, "ceiling"} +}; + +/* Check if current scanstring value is a keyword */ +static enum yytokentype checkKeyword() +{ + int res = IDENT_P; + int diff; + const JsonPathKeyword *StopLow = keywords, + *StopHigh = keywords + lengthof(keywords), + *StopMiddle; + + if (scanstring.len > keywords[lengthof(keywords) - 1].len) + return (yytokentype)res; + + while (StopLow < StopHigh) + { + StopMiddle = StopLow + ((StopHigh - StopLow) >> 1); + + if (StopMiddle->len == scanstring.len) + diff = pg_strncasecmp(StopMiddle->keyword, scanstring.data, + scanstring.len); + else + diff = StopMiddle->len - scanstring.len; + + if (diff < 0) + StopLow = StopMiddle + 1; + else if (diff > 0) + StopHigh = StopMiddle; + else + { + if (StopMiddle->lowercase) + diff = strncmp(StopMiddle->keyword, scanstring.data, + scanstring.len); + + if (diff == 0) + res = StopMiddle->val; + + break; + } + } + + return (yytokentype)res; +} + +static int process_integer_literal(const char *token, YYSTYPE *lval) +{ + long val; + char *endptr; + + errno = 0; + val = strtol(token, &endptr, 10); + if (*endptr != '\0' || errno == ERANGE +#ifdef HAVE_LONG_INT_64 + /* if long > 32 bits, check for overflow of int4 */ + || val != (long) ((int32) val) +#endif + ) + { + /* integer too large, treat it as a float */ + lval->str = pstrdup(token); + return NUMERIC_P; + } + lval->integer = val; + return INT_P; +} + +/* Interface to jsonpath parser */ +JsonPathItem * ParseJsonPath(const char *str, int len) +{ + JsonPathItem *parseresult; + + jsonpath_scanner_init(str, len); + + if (jsonpath_yyparse(&parseresult) != 0) + jsonpath_yyerror("invalid input"); /* shouldn't happen */ + + jsonpath_scanner_finish(); + + return parseresult; +} + +/* + * Interface functions to make flex use palloc() instead of malloc(). + * It'd be better to make these static, but flex insists otherwise. + */ + +void * jsonpath_yyalloc(yy_size_t bytes) +{ + return palloc(bytes); +} + +void * jsonpath_yyrealloc(void *ptr, yy_size_t bytes) +{ + if (ptr) + return repalloc(ptr, bytes); + else + return palloc(bytes); +} + +void jsonpath_yyfree(void *ptr) +{ + if (ptr) + pfree(ptr); +} \ No newline at end of file diff --git a/src/common/backend/utils/init/globals.cpp b/src/common/backend/utils/init/globals.cpp index 9fe1b958c..ca7479507 100644 --- a/src/common/backend/utils/init/globals.cpp +++ b/src/common/backend/utils/init/globals.cpp @@ -77,7 +77,7 @@ bool will_shutdown = false; * ********************************************/ -const uint32 GRAND_VERSION_NUM = 93017; +const uint32 GRAND_VERSION_NUM = 93018; /******************************************** * 2.VERSION NUM FOR EACH FEATURE diff --git a/src/common/interfaces/libpq/frontend_parser/gram.y b/src/common/interfaces/libpq/frontend_parser/gram.y index 29bf5cae5..0108d541a 100755 --- a/src/common/interfaces/libpq/frontend_parser/gram.y +++ b/src/common/interfaces/libpq/frontend_parser/gram.y @@ -567,7 +567,7 @@ extern THR_LOCAL bool stmt_contains_operator_plus; INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER INTERNAL INTERSECT INTERVAL INTO INVISIBLE INVOKER IP IS ISNULL ISOLATION - JOIN + JOIN JSON_EXISTS KEEP KEY KILL KEY_PATH KEY_STORE @@ -12237,6 +12237,7 @@ col_name_keyword: | INT_P | INTEGER | INTERVAL + | JSON_EXISTS | LEAST | NATIONAL | NCHAR diff --git a/src/include/catalog/upgrade_sql/rollback_catalog_maindb/rollback-post_catalog_maindb_93_018.sql b/src/include/catalog/upgrade_sql/rollback_catalog_maindb/rollback-post_catalog_maindb_93_018.sql new file mode 100644 index 000000000..74691d6bc --- /dev/null +++ b/src/include/catalog/upgrade_sql/rollback_catalog_maindb/rollback-post_catalog_maindb_93_018.sql @@ -0,0 +1,2 @@ +DROP FUNCTION IF EXISTS pg_catalog.json_exists(text, text, int2) CASCADE; +DROP FUNCTION IF EXISTS pg_catalog.json_textcontains(text, text, character varying) CASCADE; \ No newline at end of file diff --git a/src/include/catalog/upgrade_sql/rollback_catalog_otherdb/rollback-post_catalog_otherdb_93_018.sql b/src/include/catalog/upgrade_sql/rollback_catalog_otherdb/rollback-post_catalog_otherdb_93_018.sql new file mode 100644 index 000000000..74691d6bc --- /dev/null +++ b/src/include/catalog/upgrade_sql/rollback_catalog_otherdb/rollback-post_catalog_otherdb_93_018.sql @@ -0,0 +1,2 @@ +DROP FUNCTION IF EXISTS pg_catalog.json_exists(text, text, int2) CASCADE; +DROP FUNCTION IF EXISTS pg_catalog.json_textcontains(text, text, character varying) CASCADE; \ No newline at end of file diff --git a/src/include/catalog/upgrade_sql/upgrade_catalog_maindb/upgrade-post_catalog_maindb_93_018.sql b/src/include/catalog/upgrade_sql/upgrade_catalog_maindb/upgrade-post_catalog_maindb_93_018.sql new file mode 100644 index 000000000..965577084 --- /dev/null +++ b/src/include/catalog/upgrade_sql/upgrade_catalog_maindb/upgrade-post_catalog_maindb_93_018.sql @@ -0,0 +1,7 @@ +DROP FUNCTION IF EXISTS pg_catalog.json_exists(text, text, int2) CASCADE; +SET LOCAL inplace_upgrade_next_system_object_oids = IUO_PROC, 8810; +CREATE OR REPLACE FUNCTION pg_catalog.json_exists(text, text, int2) RETURNS bool LANGUAGE INTERNAL IMMUTABLE as 'json_path_exists'; + +DROP FUNCTION IF EXISTS pg_catalog.json_textcontains(text, text, character varying) CASCADE; +SET LOCAL inplace_upgrade_next_system_object_oids = IUO_PROC, 8811; +CREATE OR REPLACE FUNCTION pg_catalog.json_textcontains(text, text, character varying) RETURNS bool LANGUAGE INTERNAL IMMUTABLE as 'json_textcontains'; \ No newline at end of file diff --git a/src/include/catalog/upgrade_sql/upgrade_catalog_otherdb/upgrade-post_catalog_otherdb_93_018.sql b/src/include/catalog/upgrade_sql/upgrade_catalog_otherdb/upgrade-post_catalog_otherdb_93_018.sql new file mode 100644 index 000000000..965577084 --- /dev/null +++ b/src/include/catalog/upgrade_sql/upgrade_catalog_otherdb/upgrade-post_catalog_otherdb_93_018.sql @@ -0,0 +1,7 @@ +DROP FUNCTION IF EXISTS pg_catalog.json_exists(text, text, int2) CASCADE; +SET LOCAL inplace_upgrade_next_system_object_oids = IUO_PROC, 8810; +CREATE OR REPLACE FUNCTION pg_catalog.json_exists(text, text, int2) RETURNS bool LANGUAGE INTERNAL IMMUTABLE as 'json_path_exists'; + +DROP FUNCTION IF EXISTS pg_catalog.json_textcontains(text, text, character varying) CASCADE; +SET LOCAL inplace_upgrade_next_system_object_oids = IUO_PROC, 8811; +CREATE OR REPLACE FUNCTION pg_catalog.json_textcontains(text, text, character varying) RETURNS bool LANGUAGE INTERNAL IMMUTABLE as 'json_textcontains'; \ No newline at end of file diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index 774b56eb6..ef67eb08a 100644 --- a/src/include/parser/kwlist.h +++ b/src/include/parser/kwlist.h @@ -354,6 +354,7 @@ PG_KEYWORD("is", IS, RESERVED_KEYWORD) PG_KEYWORD("isnull", ISNULL, UNRESERVED_KEYWORD) PG_KEYWORD("isolation", ISOLATION, UNRESERVED_KEYWORD) PG_KEYWORD("join", JOIN, TYPE_FUNC_NAME_KEYWORD) +PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD) PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD) PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD) PG_KEYWORD("key_path", KEY_PATH, UNRESERVED_KEYWORD) diff --git a/src/include/utils/json.h b/src/include/utils/json.h index 70a354f1c..49e4569a1 100644 --- a/src/include/utils/json.h +++ b/src/include/utils/json.h @@ -84,5 +84,9 @@ extern Datum jsonb_set(PG_FUNCTION_ARGS); extern Datum jsonb_delete(PG_FUNCTION_ARGS); extern Datum jsonb_delete_idx(PG_FUNCTION_ARGS); extern Datum jsonb_delete_array(PG_FUNCTION_ARGS); +extern Datum json_path_exists(PG_FUNCTION_ARGS); +extern Datum json_textcontains(PG_FUNCTION_ARGS); + +extern int json_typeof_internal(text* json); #endif /* JSON_H */ diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h new file mode 100644 index 000000000..70ad74d7a --- /dev/null +++ b/src/include/utils/jsonpath.h @@ -0,0 +1,70 @@ +/* + * Copyright (c) 2020 Huawei Technologies Co.,Ltd. + * Portions Copyright (c) 2021, openGauss Contributors + * + * openGauss is licensed under Mulan PSL v2. + * You can use this software according to the terms and conditions of the Mulan PSL v2. + * You may obtain a copy of Mulan PSL v2 at: + * + * http://license.coscl.org.cn/MulanPSL2 + * + * THIS SOFTWARE IS PROVIDED ON AN "AS IS" BASIS, WITHOUT WARRANTIES OF ANY KIND, + * EITHER EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO NON-INFRINGEMENT, + * MERCHANTABILITY OR FIT FOR A PARTICULAR PURPOSE. + * See the Mulan PSL v2 for more details. + * --------------------------------------------------------------------------------------- + * + * jsonpath.h + * definition of jsonpath's parse result. + * + * + * IDENTIFICATION + * src/include/utils/jsonpath.h + * + * --------------------------------------------------------------------------------------- + */ + +#ifndef JSONPATH_H +#define JSONPATH_H + +#include "utils/json.h" + +/* jsonpath .y 和.l 中使用 BEGIN */ +#define YY_NO_UNISTD_H +union YYSTYPE; +/* jsonpath .y 和.l 中使用 END */ + +typedef enum JsonPathItemType { + JPI_NULL, + JPI_ABSOLUTE_START, + JPI_ARRAY, + JPI_OBJECT +} JsonPathItemType; + +typedef struct JsonPathItem { + JsonPathItemType type; + JsonPathItem* next; +} JsonPathItem; + +typedef struct JsonPathArrayStep { + JsonPathItemType type; + JsonPathItem* next; + List* indexes; +} JsonPathArrayStep; + +typedef struct JsonPathObjectStep { + JsonPathItemType type; + JsonPathItem* next; + char* fieldName; +} JsonPathObjectStep; + +typedef struct JsonPathParseItem { + JsonPathItem* head; + JsonPathItem* tail; +} JsonPathParseItem; + +extern JsonPathItem* MakeItemType(JsonPathItemType type); +extern JsonPathParseItem* MakePathParseItem(); +extern JsonPathItem* ParseJsonPath(const char* str, int len); + +#endif /* JSONPATH_H */ \ No newline at end of file diff --git a/src/test/regress/expected/json_and_jsonb.out b/src/test/regress/expected/json_and_jsonb.out index 5a6411fbe..d867b9e47 100644 --- a/src/test/regress/expected/json_and_jsonb.out +++ b/src/test/regress/expected/json_and_jsonb.out @@ -98,7 +98,9 @@ select oid,* from pg_proc where proname like '%json%' order by oid; 5613 | jsonb_delete | 11 | 10 | 12 | 1 | 0 | 0 | - | f | f | f | f | t | f | i | 2 | 0 | 3802 | 3802 25 | | | | | jsonb_delete | | | | | f | f | f | f | | 0 | f | | | 3802 25 | 5614 | jsonb_delete | 11 | 10 | 12 | 1 | 0 | 0 | - | f | f | f | f | t | f | i | 2 | 0 | 3802 | 3802 1009 | | | | | jsonb_delete_array | | | | | f | f | f | f | | 0 | f | | | 3802 1009 | 5719 | capture_view_to_json | 11 | 10 | 12 | 1 | 0 | 0 | - | f | f | f | f | f | f | v | 2 | 0 | 23 | 25 23 | | {i,i} | {view_name,is_all_db} | | capture_view_to_json | | | | | f | f | f | f | | 0 | f | | | 25 23 | -(89 rows) + 8810 | json_exists | 11 | 10 | 12 | 1 | 0 | 0 | - | f | f | f | f | f | f | i | 3 | 0 | 16 | 25 25 21 | | | | | json_path_exists | | | | | f | f | f | f | | 0 | f | | | 25 25 21 | + 8811 | json_textcontains | 11 | 10 | 12 | 1 | 0 | 0 | - | f | f | f | f | f | f | i | 3 | 0 | 16 | 25 25 2275 | | | | | json_textcontains | | | | | f | f | f | f | | 0 | f | | | 25 25 2275 | +(91 rows) select * from pg_aggregate where aggfnoid in (3124, 3403) order by aggfnoid; aggfnoid | aggtransfn | aggcollectfn | aggfinalfn | aggsortop | aggtranstype | agginitval | agginitcollect | aggkind | aggnumdirectargs diff --git a/src/test/regress/expected/jsonpath.out b/src/test/regress/expected/jsonpath.out new file mode 100644 index 000000000..4a5294074 --- /dev/null +++ b/src/test/regress/expected/jsonpath.out @@ -0,0 +1,468 @@ +DROP SCHEMA IF EXISTS test_jsonpath CASCADE; +NOTICE: schema "test_jsonpath" does not exist, skipping +CREATE SCHEMA test_jsonpath; +SET CURRENT_SCHEMA TO test_jsonpath ; +CREATE TABLE t (name VARCHAR2(100)); +INSERT INTO t VALUES ('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1]'); +INSERT INTO t VALUES ('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]]'); +INSERT INTO t VALUES ('[{"first":"Mary"}, {"last":"Jones"}]'); +INSERT INTO t VALUES ('[{"first":"Jeff"}, {"last":"Williams"}]'); +INSERT INTO t VALUES ('[{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}]'); +INSERT INTO t VALUES ('[{"first":"Jean"}, {"middle":"Anne"}, {"middle":"Alice"}, {"last":"Brown"}]'); +INSERT INTO t VALUES ('[{"first":1}, {"middle":2}, {"last":3}]'); +INSERT INTO t VALUES (NULL); +INSERT INTO t VALUES ('This is not well-formed JSON data'); +CREATE TABLE families (family_doc CLOB); +INSERT INTO families +VALUES ('{"family" : {"id":10, "ages":[40,38,12], "address" : {"street" : "10 Main Street"}}}'); +INSERT INTO families +VALUES ('{"family" : {"id":11, "ages":[42,40,10,5], "address" : {"street" : "200 East Street", "apt" : 20}}}'); +INSERT INTO families +VALUES ('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}'); +INSERT INTO families VALUES ('This is not well-formed JSON data'); +-- JsonPath grammar +SELECT name FROM t WHERE JSON_EXISTS(name, '$'); + name +----------------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1] + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] + [{"first":"Mary"}, {"last":"Jones"}] + [{"first":"Jeff"}, {"last":"Williams"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"middle":"Alice"}, {"last":"Brown"}] + [{"first":1}, {"middle":2}, {"last":3}] +(7 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0]'); + name +----------------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1] + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] + [{"first":"Mary"}, {"last":"Jones"}] + [{"first":"Jeff"}, {"last":"Williams"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"middle":"Alice"}, {"last":"Brown"}] + [{"first":1}, {"middle":2}, {"last":3}] +(7 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[*]'); + name +----------------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1] + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] + [{"first":"Mary"}, {"last":"Jones"}] + [{"first":"Jeff"}, {"last":"Williams"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"middle":"Alice"}, {"last":"Brown"}] + [{"first":1}, {"middle":2}, {"last":3}] +(7 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[99]'); + name +------ +(0 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0,2]'); + name +----------------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1] + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] + [{"first":"Mary"}, {"last":"Jones"}] + [{"first":"Jeff"}, {"last":"Williams"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"middle":"Alice"}, {"last":"Brown"}] + [{"first":1}, {"middle":2}, {"last":3}] +(7 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[2,0,1]'); + name +----------------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1] + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] + [{"first":"Mary"}, {"last":"Jones"}] + [{"first":"Jeff"}, {"last":"Williams"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"middle":"Alice"}, {"last":"Brown"}] + [{"first":1}, {"middle":2}, {"last":3}] +(7 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0 to 2]'); + name +----------------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1] + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] + [{"first":"Mary"}, {"last":"Jones"}] + [{"first":"Jeff"}, {"last":"Williams"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"middle":"Alice"}, {"last":"Brown"}] + [{"first":1}, {"middle":2}, {"last":3}] +(7 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[3 to 3]'); + name +----------------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1] + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] + [{"first":"Jean"}, {"middle":"Anne"}, {"middle":"Alice"}, {"last":"Brown"}] +(3 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[2 to 0]'); + name +----------------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1] + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] + [{"first":"Mary"}, {"last":"Jones"}] + [{"first":"Jeff"}, {"last":"Williams"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"middle":"Alice"}, {"last":"Brown"}] + [{"first":1}, {"middle":2}, {"last":3}] +(7 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[2].*.*'); + name +------ +(0 rows) + +SELECT family_doc FROM families WHERE JSON_EXISTS(family_doc, '$.family'); + family_doc +----------------------------------------------------------------------------------------------------- + {"family" : {"id":10, "ages":[40,38,12], "address" : {"street" : "10 Main Street"}}} + {"family" : {"id":11, "ages":[42,40,10,5], "address" : {"street" : "200 East Street", "apt" : 20}}} + {"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}} +(3 rows) + +SELECT family_doc FROM families WHERE JSON_EXISTS(family_doc, '$.*'); + family_doc +----------------------------------------------------------------------------------------------------- + {"family" : {"id":10, "ages":[40,38,12], "address" : {"street" : "10 Main Street"}}} + {"family" : {"id":11, "ages":[42,40,10,5], "address" : {"street" : "200 East Street", "apt" : 20}}} + {"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}} +(3 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[3][1]'); + name +-------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] +(1 row) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[1].last'); + name +----------------------------------------- + [{"first":"Mary"}, {"last":"Jones"}] + [{"first":"Jeff"}, {"last":"Williams"}] +(2 rows) + +SELECT family_doc FROM families WHERE JSON_EXISTS(family_doc, '$.family.address.apt'); + family_doc +----------------------------------------------------------------------------------------------------- + {"family" : {"id":11, "ages":[42,40,10,5], "address" : {"street" : "200 East Street", "apt" : 20}}} + {"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}} +(2 rows) + +SELECT family_doc FROM families WHERE JSON_EXISTS(family_doc, '$.family.ages[2]'); + family_doc +----------------------------------------------------------------------------------------------------- + {"family" : {"id":10, "ages":[40,38,12], "address" : {"street" : "10 Main Street"}}} + {"family" : {"id":11, "ages":[42,40,10,5], "address" : {"street" : "200 East Street", "apt" : 20}}} +(2 rows) + +-- syntax error in jsonpath +SELECT name FROM t WHERE JSON_EXISTS(name, '$[-1]'); +ERROR: syntax error in json path expression +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0b10]'); +ERROR: syntax error in json path expression +SELECT name FROM t WHERE JSON_EXISTS(name, '$[1'); +ERROR: syntax error in json path expression +SELECT name FROM t WHERE JSON_EXISTS(name, '$[1+2]'); +ERROR: syntax error in json path expression +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0.1]'); +ERROR: syntax error in json path expression +SELECT name FROM t WHERE JSON_EXISTS(name, 'NULL'); +ERROR: syntax error in json path expression +SELECT name FROM t WHERE JSON_EXISTS(name, NULL); +ERROR: the json path expression is not of text type +-- json_exists +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0].first'); + name +----------------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1] + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] + [{"first":"Mary"}, {"last":"Jones"}] + [{"first":"Jeff"}, {"last":"Williams"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"middle":"Alice"}, {"last":"Brown"}] + [{"first":1}, {"middle":2}, {"last":3}] +(7 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[1,2].last'); + name +-------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1] + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] + [{"first":"Mary"}, {"last":"Jones"}] + [{"first":"Jeff"}, {"last":"Williams"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}] + [{"first":1}, {"middle":2}, {"last":3}] +(6 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[1 to 2].last'); + name +-------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1] + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] + [{"first":"Mary"}, {"last":"Jones"}] + [{"first":"Jeff"}, {"last":"Williams"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}] + [{"first":1}, {"middle":2}, {"last":3}] +(6 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[1].first'); + name +------ +(0 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0].first[1]'); + name +------ +(0 rows) + +SELECT name FROM t WHERE JSON_EXISTS(NULL, '$'); + name +------ +(0 rows) + +SELECT JSON_EXISTS('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}]', '$[0].first'); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}]', '$[2 to 1].*'); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}]', '$[*].last'); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS('This is not well-formed JSON data', '$[0].first'); + json_exists +------------- + f +(1 row) + +-- json_exists with on error +SELECT name FROM t WHERE JSON_EXISTS(name, '$' FALSE ON ERROR); + name +----------------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1] + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] + [{"first":"Mary"}, {"last":"Jones"}] + [{"first":"Jeff"}, {"last":"Williams"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"middle":"Alice"}, {"last":"Brown"}] + [{"first":1}, {"middle":2}, {"last":3}] +(7 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$' TRUE ON ERROR); + name +----------------------------------------------------------------------------- + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1] + [{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]] + [{"first":"Mary"}, {"last":"Jones"}] + [{"first":"Jeff"}, {"last":"Williams"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}] + [{"first":"Jean"}, {"middle":"Anne"}, {"middle":"Alice"}, {"last":"Brown"}] + [{"first":1}, {"middle":2}, {"last":3}] + This is not well-formed JSON data +(8 rows) + +SELECT name FROM t WHERE JSON_EXISTS(name, '$' ERROR ON ERROR); +ERROR: the input is not a well-formed json data +SELECT JSON_EXISTS('This is not well-formed JSON data', '$[0].first' FALSE ON ERROR); + json_exists +------------- + f +(1 row) + +SELECT JSON_EXISTS('This is not well-formed JSON data', '$[0].first' TRUE ON ERROR); + json_exists +------------- + t +(1 row) + +SELECT JSON_EXISTS('This is not well-formed JSON data', '$[0].first' ERROR ON ERROR); +ERROR: the input is not a well-formed json data +CONTEXT: referenced column: json_exists +PREPARE stmt1 AS SELECT JSON_EXISTS($1,$2); +EXECUTE stmt1('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}]','$[0].first'); + json_exists +------------- + t +(1 row) + +EXECUTE stmt1('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}]','$[0].last'); + json_exists +------------- + f +(1 row) + +EXECUTE stmt1('This is not well-formed JSON data','$[0].last'); + json_exists +------------- + f +(1 row) + +DEALLOCATE PREPARE stmt1; +PREPARE stmt1 AS SELECT JSON_EXISTS($1,$2 TRUE ON ERROR); +EXECUTE stmt1('This is not well-formed JSON data','$[0].last'); + json_exists +------------- + t +(1 row) + +DEALLOCATE PREPARE stmt1; +PREPARE stmt1 AS SELECT JSON_EXISTS($1,$2 FALSE ON ERROR); +EXECUTE stmt1('This is not well-formed JSON data','$[0].last'); + json_exists +------------- + f +(1 row) + +DEALLOCATE PREPARE stmt1; +PREPARE stmt1 AS SELECT JSON_EXISTS($1,$2 ERROR ON ERROR); +EXECUTE stmt1('This is not well-formed JSON data','$[0].last'); +ERROR: the input is not a well-formed json data +CONTEXT: referenced column: json_exists +DEALLOCATE PREPARE stmt1; +-- json_textcontains +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', '10'); + family_doc +----------------------------------------------------------------------------------------------------- + {"family" : {"id":10, "ages":[40,38,12], "address" : {"street" : "10 Main Street"}}} + {"family" : {"id":11, "ages":[42,40,10,5], "address" : {"street" : "200 East Street", "apt" : 20}}} + {"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}} +(3 rows) + +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', '25, 5'); + family_doc +----------------------------------------------------------------------------------------------- + {"family" : {"id":10, "ages":[40,38,12], "address" : {"street" : "10 Main Street"}}} + {"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}} +(2 rows) + +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', 'West'); + family_doc +------------ +(0 rows) + +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', 'Oak Street'); + family_doc +----------------------------------------------------------------------------------------------- + {"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}} +(1 row) + +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', 'oak street'); + family_doc +----------------------------------------------------------------------------------------------- + {"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}} +(1 row) + +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', '25 23, Oak Street'); + family_doc +----------------------------------------------------------------------------------------------- + {"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}} +(1 row) + +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', 'Oak Street 10'); + family_doc +----------------------------------------------------------------------------------------------- + {"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}} +(1 row) + +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', '12 25 23 300 Oak Street 10'); + family_doc +----------------------------------------------------------------------------------------------- + {"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}} +(1 row) + +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family.id', 'Oak Street'); + family_doc +------------ +(0 rows) + +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', 'ak street'); + family_doc +------------ +(0 rows) + +PREPARE stmt2 AS SELECT JSON_TEXTCONTAINS($1, $2, $3); +EXECUTE stmt2(NULL, '$.family', 'data'); + json_textcontains +------------------- + +(1 row) + +EXECUTE stmt2('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , '$.family', '12'); + json_textcontains +------------------- + t +(1 row) + +EXECUTE stmt2('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , '$.family', 'K STREET'); + json_textcontains +------------------- + f +(1 row) + +EXECUTE stmt2('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , NULL, 'data'); +ERROR: the json path expression is not of text type +CONTEXT: referenced column: json_textcontains +SELECT JSON_TEXTCONTAINS('This is not well-formed JSON data', '$.family', 'data'); + json_textcontains +------------------- + f +(1 row) + +SELECT JSON_TEXTCONTAINS(NULL, '$.family', 'data'); + json_textcontains +------------------- + +(1 row) + +SELECT JSON_TEXTCONTAINS('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , '$.family', '12'); + json_textcontains +------------------- + t +(1 row) + +SELECT JSON_TEXTCONTAINS('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , '$.family', '12, OAK STREET'); + json_textcontains +------------------- + t +(1 row) + +SELECT JSON_TEXTCONTAINS('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , '$.family', 'K STREET'); + json_textcontains +------------------- + f +(1 row) + +SELECT JSON_TEXTCONTAINS('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , NULL, 'data'); +ERROR: the json path expression is not of text type +CONTEXT: referenced column: json_textcontains +DROP SCHEMA test_jsonpath CASCADE; +NOTICE: drop cascades to 2 other objects +DETAIL: drop cascades to table t +drop cascades to table families diff --git a/src/test/regress/expected/substr.out b/src/test/regress/expected/substr.out index 793907e73..6fa14a64f 100644 --- a/src/test/regress/expected/substr.out +++ b/src/test/regress/expected/substr.out @@ -98,7 +98,7 @@ ERROR: negative substring length not allowed -- If no third argument (length) is provided, the length to the end of the -- string is assumed. SELECT substr(f1, 99995) from toasttest; -ERROR: syntax error at or near "ERROR" +ERROR: syntax error at or near "ERROR:" LINE 1: ERROR: negative substring length not allowed ^ -- If start plus length is > string length, the result is truncated to @@ -209,7 +209,7 @@ ERROR: negative substring length not allowed -- If no third argument (length) is provided, the length to the end of the -- string is assumed. SELECT substr(f1, 99995) from toasttest; -ERROR: syntax error at or near "ERROR" +ERROR: syntax error at or near "ERROR:" LINE 1: ERROR: negative substring length not allowed ^ -- If start plus length is > string length, the result is truncated to diff --git a/src/test/regress/parallel_schedule0 b/src/test/regress/parallel_schedule0 index 0a209c036..34b6393c2 100644 --- a/src/test/regress/parallel_schedule0 +++ b/src/test/regress/parallel_schedule0 @@ -923,7 +923,7 @@ test: advisory_lock # Another group of parallel tests # ---------- test: cluster dependency bitmapops tsdicts functional_deps -test: json_and_jsonb json jsonb jsonb2 +test: json_and_jsonb json jsonb jsonb2 jsonpath #test: guc # test for vec sonic hash diff --git a/src/test/regress/parallel_schedule0B b/src/test/regress/parallel_schedule0B index 0e8159456..3957ed56b 100644 --- a/src/test/regress/parallel_schedule0B +++ b/src/test/regress/parallel_schedule0B @@ -426,7 +426,7 @@ test: advisory_lock # Another group of parallel tests # ---------- test: cluster dependency bitmapops tsdicts functional_deps -test: json_and_jsonb json jsonb jsonb2 +test: json_and_jsonb json jsonb jsonb2 jsonpath #test: guc # test for vec sonic hash diff --git a/src/test/regress/sql/jsonpath.sql b/src/test/regress/sql/jsonpath.sql new file mode 100644 index 000000000..08673bddd --- /dev/null +++ b/src/test/regress/sql/jsonpath.sql @@ -0,0 +1,124 @@ +DROP SCHEMA IF EXISTS test_jsonpath CASCADE; +CREATE SCHEMA test_jsonpath; +SET CURRENT_SCHEMA TO test_jsonpath ; + +CREATE TABLE t (name VARCHAR2(100)); +INSERT INTO t VALUES ('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, 1]'); +INSERT INTO t VALUES ('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}, [1, 2, 3]]'); +INSERT INTO t VALUES ('[{"first":"Mary"}, {"last":"Jones"}]'); +INSERT INTO t VALUES ('[{"first":"Jeff"}, {"last":"Williams"}]'); +INSERT INTO t VALUES ('[{"first":"Jean"}, {"middle":"Anne"}, {"last":"Brown"}]'); +INSERT INTO t VALUES ('[{"first":"Jean"}, {"middle":"Anne"}, {"middle":"Alice"}, {"last":"Brown"}]'); +INSERT INTO t VALUES ('[{"first":1}, {"middle":2}, {"last":3}]'); +INSERT INTO t VALUES (NULL); +INSERT INTO t VALUES ('This is not well-formed JSON data'); + + +CREATE TABLE families (family_doc CLOB); +INSERT INTO families +VALUES ('{"family" : {"id":10, "ages":[40,38,12], "address" : {"street" : "10 Main Street"}}}'); +INSERT INTO families +VALUES ('{"family" : {"id":11, "ages":[42,40,10,5], "address" : {"street" : "200 East Street", "apt" : 20}}}'); +INSERT INTO families +VALUES ('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}'); + +INSERT INTO families VALUES ('This is not well-formed JSON data'); + +-- JsonPath grammar +SELECT name FROM t WHERE JSON_EXISTS(name, '$'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0]'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[*]'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[99]'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0,2]'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[2,0,1]'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0 to 2]'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[3 to 3]'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[2 to 0]'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[2].*.*'); +SELECT family_doc FROM families WHERE JSON_EXISTS(family_doc, '$.family'); +SELECT family_doc FROM families WHERE JSON_EXISTS(family_doc, '$.*'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[3][1]'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[1].last'); +SELECT family_doc FROM families WHERE JSON_EXISTS(family_doc, '$.family.address.apt'); +SELECT family_doc FROM families WHERE JSON_EXISTS(family_doc, '$.family.ages[2]'); + +-- syntax error in jsonpath +SELECT name FROM t WHERE JSON_EXISTS(name, '$[-1]'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0b10]'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[1'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[1+2]'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0.1]'); +SELECT name FROM t WHERE JSON_EXISTS(name, 'NULL'); +SELECT name FROM t WHERE JSON_EXISTS(name, NULL); + +-- json_exists +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0].first'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[1,2].last'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[1 to 2].last'); + +SELECT name FROM t WHERE JSON_EXISTS(name, '$[1].first'); +SELECT name FROM t WHERE JSON_EXISTS(name, '$[0].first[1]'); + +SELECT name FROM t WHERE JSON_EXISTS(NULL, '$'); +SELECT JSON_EXISTS('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}]', '$[0].first'); +SELECT JSON_EXISTS('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}]', '$[2 to 1].*'); +SELECT JSON_EXISTS('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}]', '$[*].last'); +SELECT JSON_EXISTS('This is not well-formed JSON data', '$[0].first'); + +-- json_exists with on error +SELECT name FROM t WHERE JSON_EXISTS(name, '$' FALSE ON ERROR); +SELECT name FROM t WHERE JSON_EXISTS(name, '$' TRUE ON ERROR); +SELECT name FROM t WHERE JSON_EXISTS(name, '$' ERROR ON ERROR); + +SELECT JSON_EXISTS('This is not well-formed JSON data', '$[0].first' FALSE ON ERROR); +SELECT JSON_EXISTS('This is not well-formed JSON data', '$[0].first' TRUE ON ERROR); +SELECT JSON_EXISTS('This is not well-formed JSON data', '$[0].first' ERROR ON ERROR); + +PREPARE stmt1 AS SELECT JSON_EXISTS($1,$2); +EXECUTE stmt1('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}]','$[0].first'); +EXECUTE stmt1('[{"first":"John"}, {"middle":"Mark"}, {"last":"Smith"}]','$[0].last'); +EXECUTE stmt1('This is not well-formed JSON data','$[0].last'); +DEALLOCATE PREPARE stmt1; +PREPARE stmt1 AS SELECT JSON_EXISTS($1,$2 TRUE ON ERROR); +EXECUTE stmt1('This is not well-formed JSON data','$[0].last'); +DEALLOCATE PREPARE stmt1; +PREPARE stmt1 AS SELECT JSON_EXISTS($1,$2 FALSE ON ERROR); +EXECUTE stmt1('This is not well-formed JSON data','$[0].last'); +DEALLOCATE PREPARE stmt1; +PREPARE stmt1 AS SELECT JSON_EXISTS($1,$2 ERROR ON ERROR); +EXECUTE stmt1('This is not well-formed JSON data','$[0].last'); +DEALLOCATE PREPARE stmt1; + +-- json_textcontains +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', '10'); +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', '25, 5'); +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', 'West'); +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', 'Oak Street'); +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', 'oak street'); +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', '25 23, Oak Street'); +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', 'Oak Street 10'); +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', '12 25 23 300 Oak Street 10'); +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family.id', 'Oak Street'); +SELECT family_doc FROM families WHERE JSON_TEXTCONTAINS(family_doc, '$.family', 'ak street'); + +PREPARE stmt2 AS SELECT JSON_TEXTCONTAINS($1, $2, $3); +EXECUTE stmt2(NULL, '$.family', 'data'); +EXECUTE stmt2('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , '$.family', '12'); +EXECUTE stmt2('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , '$.family', 'K STREET'); +EXECUTE stmt2('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , NULL, 'data'); + +SELECT JSON_TEXTCONTAINS('This is not well-formed JSON data', '$.family', 'data'); +SELECT JSON_TEXTCONTAINS(NULL, '$.family', 'data'); +SELECT JSON_TEXTCONTAINS('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , '$.family', '12'); +SELECT JSON_TEXTCONTAINS('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , '$.family', '12, OAK STREET'); +SELECT JSON_TEXTCONTAINS('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , '$.family', 'K STREET'); +SELECT JSON_TEXTCONTAINS('{"family" : {"id":12, "ages":[25,23], "address" : {"street" : "300 Oak Street", "apt" : 10}}}' + , NULL, 'data'); + +DROP SCHEMA test_jsonpath CASCADE; \ No newline at end of file