From 15a7b6c0b7421a8973d9d6801d67538c12912145 Mon Sep 17 00:00:00 2001 From: Rucha Deodhar Date: Thu, 25 May 2023 15:45:43 +0530 Subject: [PATCH] MDEV-30145: JSON_TABLE: allow to retrieve the key when iterating on JSON objects Idea behind implementation: We get the json object specified by the json path. Then, transform it into key-value pairs by going over the json. Get each key-value pair one-by-one and return the result. --- mysql-test/main/func_json.result | 192 ++++++++++++++++++++++++++++++- mysql-test/main/func_json.test | 145 ++++++++++++++++++++++- sql/item_create.cc | 22 ++++ sql/item_jsonfunc.cc | 139 +++++++++++++++++++++- sql/item_jsonfunc.h | 33 +++++- 5 files changed, 524 insertions(+), 7 deletions(-) diff --git a/mysql-test/main/func_json.result b/mysql-test/main/func_json.result index 28f9a23a1a886..d001bb326f861 100644 --- a/mysql-test/main/func_json.result +++ b/mysql-test/main/func_json.result @@ -671,8 +671,8 @@ DROP TABLE t1; SELECT JSON_EXTRACT( '{"foo":"bar"}', '$[*].*' ); JSON_EXTRACT( '{"foo":"bar"}', '$[*].*' ) NULL -SELECT JSON_EXTRACT( '{"foo":"bar"}', '$[*]' ); -JSON_EXTRACT( '{"foo":"bar"}', '$[*]' ) +SELECT JSON_EXTRACT( '{"foo":"bar"}', '$[*]'); +JSON_EXTRACT( '{"foo":"bar"}', '$[*]') NULL select JSON_EXTRACT('{"name":"value"}', '$.name') = 'value'; JSON_EXTRACT('{"name":"value"}', '$.name') = 'value' @@ -4759,3 +4759,191 @@ SELECT JSON_SCHEMA_VALID(NULL, NULL); JSON_SCHEMA_VALID(NULL, NULL) NULL # End of 11.1 test +# Beginning of 11.2 +# +# MDEV-30145: JSON_TABLE: allow to retrieve the key when iterating on JSON objects +# +# Checking json table with NULL and empty json doc +SELECT jt.* +FROM JSON_TABLE( +NULL, '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +# With Empty and NULL +SELECT JSON_KEY_VALUE(NULL, '$.a'); +JSON_KEY_VALUE(NULL, '$.a') +NULL +SELECT JSON_KEY_VALUE('', '$.a'); +JSON_KEY_VALUE('', '$.a') +NULL +SELECT JSON_KEY_VALUE('[1,2,3]', ''); +JSON_KEY_VALUE('[1,2,3]', '') +NULL +SELECT JSON_KEY_VALUE('[1,2,3]', NULL); +JSON_KEY_VALUE('[1,2,3]', NULL) +NULL +# With scalars +SELECT JSON_KEY_VALUE('2', '$'); +JSON_KEY_VALUE('2', '$') +NULL +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('2', '$'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +SELECT JSON_KEY_VALUE('"some_string"', '$'); +JSON_KEY_VALUE('"some_string"', '$') +NULL +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('"some_string"', '$'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +SELECT JSON_KEY_VALUE('"some_string"', '$.a'); +JSON_KEY_VALUE('"some_string"', '$.a') +NULL +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('"some_string"', '$.a'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +SELECT JSON_KEY_VALUE('"some_string"', '$[0]'); +JSON_KEY_VALUE('"some_string"', '$[0]') +NULL +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('"some_string"', '$[0]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +SELECT JSON_KEY_VALUE('false', '$[0]'); +JSON_KEY_VALUE('false', '$[0]') +NULL +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('false', '$[0]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +# With non-scalar +# With array +SELECT JSON_KEY_VALUE('[]', '[0]'); +JSON_KEY_VALUE('[]', '[0]') +NULL +SELECT JSON_KEY_VALUE('[1, 2, 3]', '$[0]'); +JSON_KEY_VALUE('[1, 2, 3]', '$[0]') +NULL +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('[1, 2, 3]', '$[0]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +SELECT JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0]'); +JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0]') +NULL +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +SELECT JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0].a'); +JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0].a') +NULL +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0].a'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +SELECT JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0][1]'); +JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0][1]') +NULL +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0][1]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +SELECT JSON_KEY_VALUE('[[1, {"key1":"val1", "key2":"val2"}, 3], 2, 3]', '$[0][1]'); +JSON_KEY_VALUE('[[1, {"key1":"val1", "key2":"val2"}, 3], 2, 3]', '$[0][1]') +[{"key": "key1", "value": "val1"}, {"key": "key2", "value": "val2"}] +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('[[1, {"key1":"val1", "key2":"val2"}, 3], 2, 3]', '$[0][1]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +key1 val1 1 +key2 val2 2 +SELECT JSON_KEY_VALUE('[[1, {"key1":"val1", "key2":"val2"}, 3], 2, 3]', '$[0][1].key1'); +JSON_KEY_VALUE('[[1, {"key1":"val1", "key2":"val2"}, 3], 2, 3]', '$[0][1].key1') +NULL +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('[[1, {"key1":"val1", "key2":"val2"}, 3], 2, 3]', '$[0][1].key1'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +SELECT JSON_KEY_VALUE('[[1, [{"key1":"val1", "key2":"val2"}], 3], 2, 3]', '$[0][1]'); +JSON_KEY_VALUE('[[1, [{"key1":"val1", "key2":"val2"}], 3], 2, 3]', '$[0][1]') +NULL +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('[[1, [{"key1":"val1", "key2":"val2"}], 3], 2, 3]', '$[0][1]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +SELECT JSON_KEY_VALUE('[[1, [{"key1":"val1", "key2":"val2"}], 3], 2, 3]', '$[0][1][0]'); +JSON_KEY_VALUE('[[1, [{"key1":"val1", "key2":"val2"}], 3], 2, 3]', '$[0][1][0]') +[{"key": "key1", "value": "val1"}, {"key": "key2", "value": "val2"}] +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('[[1, [{"key1":"val1", "key2":"val2"}], 3], 2, 3]', '$[0][1][0]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +key1 val1 1 +key2 val2 2 +# With object +SELECT JSON_KEY_VALUE('{}', '$.key1'); +JSON_KEY_VALUE('{}', '$.key1') +NULL +SELECT JSON_KEY_VALUE('{"key1":"val1", "key2":"val2"}', '$'); +JSON_KEY_VALUE('{"key1":"val1", "key2":"val2"}', '$') +[{"key": "key1", "value": "val1"}, {"key": "key2", "value": "val2"}] +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('{"key1":"val1", "key2":"val2"}', '$'), '$[*]' + COLUMNS (k VARCHAR(11) PATH '$.key', v VARCHAR(5) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +key1 val1 1 +key2 val2 2 +SELECT JSON_KEY_VALUE('{"key1":"val1", "key2":"val2"}', '$.key1'); +JSON_KEY_VALUE('{"key1":"val1", "key2":"val2"}', '$.key1') +NULL +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('{"key1":"val1", "key2":"val2"}', '$.key1'), '$[*]' + COLUMNS (k VARCHAR(11) PATH '$.key', v VARCHAR(5) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +SELECT JSON_KEY_VALUE('{"key1":{"a":1, "b":2}, "key2":"val2"}', '$.key1'); +JSON_KEY_VALUE('{"key1":{"a":1, "b":2}, "key2":"val2"}', '$.key1') +[{"key": "a", "value": 1}, {"key": "b", "value": 2}] +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('{"key1":{"a":1, "b":2}, "key2":"val2"}', '$.key1'), '$[*]' + COLUMNS (k VARCHAR(11) PATH '$.key', v VARCHAR(5) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +a 1 1 +b 2 2 +SELECT JSON_KEY_VALUE('{"key1":{"a":1, "b": [1,2,3, {"some_key":"some_val", "c":3}]}, "key2":"val2"}', '$.key1.b[3]'); +JSON_KEY_VALUE('{"key1":{"a":1, "b": [1,2,3, {"some_key":"some_val", "c":3}]}, "key2":"val2"}', '$.key1.b[3]') +[{"key": "some_key", "value": "some_val"}, {"key": "c", "value": 3}] +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('{"key1":{"a":1, "b": [1,2,3, {"some_key":"some_val", "c":3}]}, "key2":"val2"}', '$.key1.b[3]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +some_key some_val 1 +c 3 2 +SELECT JSON_KEY_VALUE('{"key1":{"a":1, "b": [1,2,3, {"some_key":"some_val", "c":3}]}, "key2":"val2"}', '$.key1.b[0]'); +JSON_KEY_VALUE('{"key1":{"a":1, "b": [1,2,3, {"some_key":"some_val", "c":3}]}, "key2":"val2"}', '$.key1.b[0]') +NULL +SELECT jt.* +FROM JSON_TABLE( +JSON_KEY_VALUE('{"key1":{"a":1, "b": [1,2,3, {"some_key":"some_val", "c":3}]}, "key2":"val2"}', '$.key1.b[0]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; +k v id +# End of 11.2 test diff --git a/mysql-test/main/func_json.test b/mysql-test/main/func_json.test index d1671b11baf6d..4f7c1eaebcd50 100644 --- a/mysql-test/main/func_json.test +++ b/mysql-test/main/func_json.test @@ -338,7 +338,7 @@ DROP TABLE t1; # MDEV-12324 Wrong result (phantom array value) on JSON_EXTRACT. # SELECT JSON_EXTRACT( '{"foo":"bar"}', '$[*].*' ); -SELECT JSON_EXTRACT( '{"foo":"bar"}', '$[*]' ); +SELECT JSON_EXTRACT( '{"foo":"bar"}', '$[*]'); # # MDEV-12604 Comparison of JSON_EXTRACT result differs with Mysql. @@ -3640,3 +3640,146 @@ SELECT JSON_SCHEMA_VALID(NULL, '{}'); SELECT JSON_SCHEMA_VALID(NULL, NULL); --echo # End of 11.1 test + +--echo # Beginning of 11.2 + +--echo # +--echo # MDEV-30145: JSON_TABLE: allow to retrieve the key when iterating on JSON objects +--echo # + +--echo # Checking json table with NULL and empty json doc + +SELECT jt.* +FROM JSON_TABLE( + NULL, '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +--echo # With Empty and NULL + +SELECT JSON_KEY_VALUE(NULL, '$.a'); +SELECT JSON_KEY_VALUE('', '$.a'); +SELECT JSON_KEY_VALUE('[1,2,3]', ''); +SELECT JSON_KEY_VALUE('[1,2,3]', NULL); + +--echo # With scalars + +SELECT JSON_KEY_VALUE('2', '$'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('2', '$'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('"some_string"', '$'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('"some_string"', '$'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('"some_string"', '$.a'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('"some_string"', '$.a'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('"some_string"', '$[0]'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('"some_string"', '$[0]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('false', '$[0]'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('false', '$[0]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +--echo # With non-scalar + +--echo # With array + +SELECT JSON_KEY_VALUE('[]', '[0]'); + + +SELECT JSON_KEY_VALUE('[1, 2, 3]', '$[0]'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('[1, 2, 3]', '$[0]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0]'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0].a'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0].a'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0][1]'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('[[1, 2, 3], 2, 3]', '$[0][1]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('[[1, {"key1":"val1", "key2":"val2"}, 3], 2, 3]', '$[0][1]'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('[[1, {"key1":"val1", "key2":"val2"}, 3], 2, 3]', '$[0][1]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('[[1, {"key1":"val1", "key2":"val2"}, 3], 2, 3]', '$[0][1].key1'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('[[1, {"key1":"val1", "key2":"val2"}, 3], 2, 3]', '$[0][1].key1'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('[[1, [{"key1":"val1", "key2":"val2"}], 3], 2, 3]', '$[0][1]'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('[[1, [{"key1":"val1", "key2":"val2"}], 3], 2, 3]', '$[0][1]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('[[1, [{"key1":"val1", "key2":"val2"}], 3], 2, 3]', '$[0][1][0]'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('[[1, [{"key1":"val1", "key2":"val2"}], 3], 2, 3]', '$[0][1][0]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +--echo # With object + +SELECT JSON_KEY_VALUE('{}', '$.key1'); + +SELECT JSON_KEY_VALUE('{"key1":"val1", "key2":"val2"}', '$'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('{"key1":"val1", "key2":"val2"}', '$'), '$[*]' + COLUMNS (k VARCHAR(11) PATH '$.key', v VARCHAR(5) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('{"key1":"val1", "key2":"val2"}', '$.key1'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('{"key1":"val1", "key2":"val2"}', '$.key1'), '$[*]' + COLUMNS (k VARCHAR(11) PATH '$.key', v VARCHAR(5) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('{"key1":{"a":1, "b":2}, "key2":"val2"}', '$.key1'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('{"key1":{"a":1, "b":2}, "key2":"val2"}', '$.key1'), '$[*]' + COLUMNS (k VARCHAR(11) PATH '$.key', v VARCHAR(5) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('{"key1":{"a":1, "b": [1,2,3, {"some_key":"some_val", "c":3}]}, "key2":"val2"}', '$.key1.b[3]'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('{"key1":{"a":1, "b": [1,2,3, {"some_key":"some_val", "c":3}]}, "key2":"val2"}', '$.key1.b[3]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +SELECT JSON_KEY_VALUE('{"key1":{"a":1, "b": [1,2,3, {"some_key":"some_val", "c":3}]}, "key2":"val2"}', '$.key1.b[0]'); +SELECT jt.* +FROM JSON_TABLE( + JSON_KEY_VALUE('{"key1":{"a":1, "b": [1,2,3, {"some_key":"some_val", "c":3}]}, "key2":"val2"}', '$.key1.b[0]'), '$[*]' + COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt; + +--echo # End of 11.2 test diff --git a/sql/item_create.cc b/sql/item_create.cc index 1c8cecd940bd8..0a26285f13565 100644 --- a/sql/item_create.cc +++ b/sql/item_create.cc @@ -1364,6 +1364,18 @@ class Create_func_json_schema_valid: public Create_func_arg2 virtual ~Create_func_json_schema_valid() {} }; +class Create_func_json_key_value : public Create_func_arg2 +{ +public: + virtual Item *create_2_arg(THD *thd, Item *arg1, Item *arg2); + + static Create_func_json_key_value s_singleton; + +protected: + Create_func_json_key_value() = default; + virtual ~Create_func_json_key_value() = default; +}; + class Create_func_last_day : public Create_func_arg1 { @@ -4427,6 +4439,15 @@ Create_func_json_schema_valid::create_2_arg(THD *thd, Item *arg1, Item *arg2) return new (thd->mem_root) Item_func_json_schema_valid(thd, arg1, arg2); } +Create_func_json_key_value Create_func_json_key_value::s_singleton; + +Item* +Create_func_json_key_value::create_2_arg(THD *thd, Item *arg1, Item *arg2) +{ + status_var_increment(thd->status_var.feature_json); + return new (thd->mem_root) Item_func_json_key_value(thd, arg1, arg2); +} + Create_func_lcase Create_func_lcase::s_singleton; @@ -5811,6 +5832,7 @@ Native_func_registry func_array[] = { { STRING_WITH_LEN("JSON_EXISTS") }, BUILDER(Create_func_json_exists)}, { { STRING_WITH_LEN("JSON_EXTRACT") }, BUILDER(Create_func_json_extract)}, { { STRING_WITH_LEN("JSON_INSERT") }, BUILDER(Create_func_json_insert)}, + { { STRING_WITH_LEN("JSON_KEY_VALUE") }, BUILDER(Create_func_json_key_value)}, { { STRING_WITH_LEN("JSON_KEYS") }, BUILDER(Create_func_json_keys)}, { { STRING_WITH_LEN("JSON_LENGTH") }, BUILDER(Create_func_json_length)}, { { STRING_WITH_LEN("JSON_LOOSE") }, BUILDER(Create_func_json_loose)}, diff --git a/sql/item_jsonfunc.cc b/sql/item_jsonfunc.cc index fa0a8cbec7f37..736e85cd691ff 100644 --- a/sql/item_jsonfunc.cc +++ b/sql/item_jsonfunc.cc @@ -764,12 +764,13 @@ bool Json_engine_scan::check_and_get_value_scalar(String *res, int *error) js_len= value_len; } - return st_append_json(res, json_cs, js, js_len); } -bool Json_engine_scan::check_and_get_value_complex(String *res, int *error) +bool Json_engine_scan::check_and_get_value_complex(String *res, int *error, + json_value_types + cur_value_type) { if (json_value_scalar(this)) { @@ -786,6 +787,13 @@ bool Json_engine_scan::check_and_get_value_complex(String *res, int *error) return true; } + if (cur_value_type != JSON_VALUE_UNINITIALIZED && + value_type != cur_value_type) + { + *error= 1; + return true; + } + res->set((const char *) value, (uint32)(s.c_str - tmp_value), s.cs); return false; } @@ -4847,3 +4855,130 @@ void Item_func_json_schema_valid::cleanup() DBUG_VOID_RETURN; } + + +bool Item_func_json_key_value::get_key_value(json_engine_t *je, String *str) +{ + int level= je->stack_p; + + if (str->append('[')) + goto error_return; + + while (json_scan_next(je) == 0 && je->stack_p >= level) + { + const uchar *key_start, *key_end, *value_begin; + size_t v_len; + + switch (je->state) + { + case JST_KEY: + + key_start= je->s.c_str; + do + { + key_end= je->s.c_str; + } while (json_read_keyname_chr(je) == 0); + + if (unlikely(je->s.error)) + goto error_return; + + if (json_read_value(je)) + goto error_return; + + value_begin= je->value_begin; + if (json_value_scalar(je)) + v_len= je->value_end - value_begin; + else + { + if (json_skip_level(je)) + goto error_return; + v_len= je->s.c_str - value_begin; + } + + size_t key_len= (size_t)(key_end-key_start); + + if (str->append('{') || + str->append('"') || str->append("key", 3) || str->append('"') || + str->append(": ", 2) || + str->append('"') || str->append((const char*)key_start, key_len) || str->append('"') || + str->append(", ",2) || + str->append('"') || str->append("value", 5) || str->append('"') || + str->append(": ", 2) || + str->append((const char*)value_begin, v_len) || + str->append('}') || + str->append(", ", 2)) + goto error_return; + } + } + + if (je->s.error) + goto error_return; + + if (str->length() > 1) + { + /* remove the last comma and space. */ + str->chop(); + str->chop(); + } + + /* close the array */ + if (str->append(']')) + goto error_return; + + return false; + +error_return: + str->length(0); + return true; +} + +String* Item_func_json_key_value::val_str(String *str) +{ + json_engine_t je; + + if ((null_value= args[0]->null_value) || + (null_value= args[1]->null_value)) + { + goto return_null; + } + + null_value= Json_path_extractor::extract(&tmp_str, args[0], args[1], + collation.collation); + if (null_value) + return NULL; + + json_scan_start(&je, tmp_str.charset(), (const uchar *) tmp_str.ptr(), + (const uchar *) tmp_str.ptr() + tmp_str.length()); + if (json_read_value(&je)) + { + report_json_error(str, &je, 0); + goto return_null; + } + + str->length(0); + if (get_key_value(&je, str)) + { + report_json_error(str, &je, 0); + goto return_null; + } + + return str; + +return_null: + null_value= 1; + return NULL; +} + + +bool Item_func_json_key_value::fix_length_and_dec(THD *thd) +{ + collation.set(args[0]->collation); + + tmp_str.set("", 0, collation.collation); + + max_length= args[0]->max_length*2; + set_constant_flag(args[1]->const_item()); + set_maybe_null(); + + return FALSE; +} diff --git a/sql/item_jsonfunc.h b/sql/item_jsonfunc.h index 17ffe94393885..a9bd01a386e59 100644 --- a/sql/item_jsonfunc.h +++ b/sql/item_jsonfunc.h @@ -74,7 +74,9 @@ class Json_engine_scan: public json_engine_t (const uchar *) str.end()) { } bool check_and_get_value_scalar(String *res, int *error); - bool check_and_get_value_complex(String *res, int *error); + bool check_and_get_value_complex(String *res, int *error, + json_value_types cur_value_type= + JSON_VALUE_UNINITIALIZED); }; @@ -227,7 +229,7 @@ class Item_func_json_query: public Item_json_func, bool check_and_get_value(Json_engine_scan *je, String *res, int *error) override { - return je->check_and_get_value_complex(res, error); + return je->check_and_get_value_complex(res, error, JSON_VALUE_UNINITIALIZED); } Item *get_copy(THD *thd) override { return get_item_copy(thd, this); } @@ -826,4 +828,31 @@ class Item_func_json_schema_valid: public Item_bool_func void cleanup() override; }; +class Item_func_json_key_value: public Item_json_func, + public Json_path_extractor +{ + + String tmp_str; + +public: + Item_func_json_key_value(THD *thd, Item *js, Item *i_path): + Item_json_func(thd, js, i_path) {} + LEX_CSTRING func_name_cstring() const override + { + static LEX_CSTRING name= {STRING_WITH_LEN("json_key_value") }; + return name; + } + bool fix_length_and_dec(THD *thd) override; + String *val_str(String *to) override; + bool check_and_get_value(Json_engine_scan *je, + String *res, int *error) override + { + return je->check_and_get_value_complex(res, error, JSON_VALUE_OBJECT); + } + bool get_key_value(json_engine_t *je, String *str); + Item *get_copy(THD *thd) override + { return get_item_copy(thd, this); } +}; + + #endif /* ITEM_JSONFUNC_INCLUDED */