From ed92a8f81ece766754d1edbcaf59c27a1591511d Mon Sep 17 00:00:00 2001 From: Kang Date: Mon, 28 Nov 2022 11:36:54 +0800 Subject: [PATCH] [feature](jsonb function)change jsonb_extract_string behavior and doc (#14619) 1. change jsonb_extract_string behavior: convert to string instead of NULL if the type of json path is not string 2. move jsonb tutorial doc to JSONB data type --- be/src/util/jsonb_utils.h | 7 +- be/src/vec/functions/function_jsonb.cpp | 30 +- be/test/vec/function/function_jsonb_test.cpp | 54 +- .../json-functions/jsonb_tutorial.md | 801 ------------------ .../sql-reference/Data-Types/JSONB.md | 771 ++++++++++++++++- docs/sidebars.json | 1 - .../json-functions/jsonb_tutorial.md | 798 ----------------- .../sql-reference/Data-Types/JSONB.md | 770 ++++++++++++++++- .../jsonb_p0/test_jsonb_load_and_function.out | 68 +- 9 files changed, 1631 insertions(+), 1669 deletions(-) delete mode 100644 docs/en/docs/sql-manual/sql-functions/json-functions/jsonb_tutorial.md delete mode 100644 docs/zh-CN/docs/sql-manual/sql-functions/json-functions/jsonb_tutorial.md diff --git a/be/src/util/jsonb_utils.h b/be/src/util/jsonb_utils.h index 64e125e329..22b0a57234 100644 --- a/be/src/util/jsonb_utils.h +++ b/be/src/util/jsonb_utils.h @@ -41,12 +41,15 @@ public: // get json string const std::string to_json_string(const char* data, size_t size) { doris::JsonbValue* pval = doris::JsonbDocument::createDocument(data, size)->getValue(); + return to_json_string(pval); + } + const std::string to_json_string(const JsonbValue* val) { os_.clear(); os_.seekp(0); - if (pval) { - intern_json(pval); + if (val) { + intern_json(val); } os_.put(0); diff --git a/be/src/vec/functions/function_jsonb.cpp b/be/src/vec/functions/function_jsonb.cpp index dd00e04166..ea84ddf3ae 100644 --- a/be/src/vec/functions/function_jsonb.cpp +++ b/be/src/vec/functions/function_jsonb.cpp @@ -368,6 +368,8 @@ struct JsonbExtractStringImpl { writer.reset(new JsonbWriter()); } + std::unique_ptr formater; + for (size_t i = 0; i < input_rows_count; ++i) { int l_size = loffsets[i] - loffsets[i - 1]; const auto l_raw = reinterpret_cast(&ldata[loffsets[i - 1]]); @@ -413,9 +415,33 @@ struct JsonbExtractStringImpl { StringOP::push_value_string( std::string_view(str_value->getBlob(), str_value->length()), i, res_data, res_offsets); + } else if (value->isNull()) { + StringOP::push_value_string("null", i, res_data, res_offsets); + } else if (value->isTrue()) { + StringOP::push_value_string("true", i, res_data, res_offsets); + } else if (value->isFalse()) { + StringOP::push_value_string("false", i, res_data, res_offsets); + } else if (value->isInt8()) { + StringOP::push_value_string(std::to_string(((const JsonbInt8Val*)value)->val()), + i, res_data, res_offsets); + } else if (value->isInt16()) { + StringOP::push_value_string( + std::to_string(((const JsonbInt16Val*)value)->val()), i, res_data, + res_offsets); + } else if (value->isInt32()) { + StringOP::push_value_string( + std::to_string(((const JsonbInt32Val*)value)->val()), i, res_data, + res_offsets); + } else if (value->isInt64()) { + StringOP::push_value_string( + std::to_string(((const JsonbInt64Val*)value)->val()), i, res_data, + res_offsets); } else { - StringOP::push_null_string(i, res_data, res_offsets, null_map); - continue; + if (!formater) { + formater.reset(new JsonbToJson()); + } + StringOP::push_value_string(formater->to_json_string(value), i, res_data, + res_offsets); } } } diff --git a/be/test/vec/function/function_jsonb_test.cpp b/be/test/vec/function/function_jsonb_test.cpp index 4898cea917..46ef9655dd 100644 --- a/be/test/vec/function/function_jsonb_test.cpp +++ b/be/test/vec/function/function_jsonb_test.cpp @@ -638,24 +638,26 @@ TEST(FunctionJsonbTEST, JsonbExtractStringTest) { // jsonb_extract root DataSet data_set = { {{Null(), STRING("$")}, Null()}, - {{STRING("null"), STRING("$")}, Null()}, - {{STRING("true"), STRING("$")}, Null()}, - {{STRING("false"), STRING("$")}, Null()}, - {{STRING("100"), STRING("$")}, Null()}, //int8 - {{STRING("10000"), STRING("$")}, Null()}, // int16 - {{STRING("1000000000"), STRING("$")}, Null()}, // int32 - {{STRING("1152921504606846976"), STRING("$")}, Null()}, // int64 - {{STRING("6.18"), STRING("$")}, Null()}, // double - {{STRING(R"("abcd")"), STRING("$")}, STRING("abcd")}, // string - {{STRING("{}"), STRING("$")}, Null()}, // empty object - {{STRING(R"({"k1":"v31", "k2": 300})"), STRING("$")}, Null()}, // object - {{STRING("[]"), STRING("$")}, Null()}, // empty array - {{STRING("[123, 456]"), STRING("$")}, Null()}, // int array - {{STRING(R"(["abc", "def"])"), STRING("$")}, Null()}, // string array + {{STRING("null"), STRING("$")}, STRING("null")}, + {{STRING("true"), STRING("$")}, STRING("true")}, + {{STRING("false"), STRING("$")}, STRING("false")}, + {{STRING("100"), STRING("$")}, STRING("100")}, //int8 + {{STRING("10000"), STRING("$")}, STRING("10000")}, // int16 + {{STRING("1000000000"), STRING("$")}, STRING("1000000000")}, // int32 + {{STRING("1152921504606846976"), STRING("$")}, STRING("1152921504606846976")}, // int64 + {{STRING("6.18"), STRING("$")}, STRING("6.18")}, // double + {{STRING(R"("abcd")"), STRING("$")}, STRING("abcd")}, // string + {{STRING("{}"), STRING("$")}, STRING("{}")}, // empty object + {{STRING(R"({"k1":"v31", "k2": 300})"), STRING("$")}, + STRING(R"({"k1":"v31","k2":300})")}, // object + {{STRING("[]"), STRING("$")}, STRING("[]")}, // empty array + {{STRING("[123, 456]"), STRING("$")}, STRING("[123,456]")}, // int array + {{STRING(R"(["abc", "def"])"), STRING("$")}, + STRING(R"(["abc","def"])")}, // string array {{STRING(R"([null, true, false, 100, 6.18, "abc"])"), STRING("$")}, - Null()}, // multi type array + STRING(R"([null,true,false,100,6.18,"abc"])")}, // multi type array {{STRING(R"([{"k1":"v41", "k2": 400}, 1, "a", 3.14])"), STRING("$")}, - Null()}, // complex array + STRING(R"([{"k1":"v41","k2":400},1,"a",3.14])")}, // complex array }; check_function(func_name, input_types, data_set); @@ -712,34 +714,34 @@ TEST(FunctionJsonbTEST, JsonbExtractStringTest) { {{STRING("{}"), STRING("$[1]")}, Null()}, // empty object {{STRING(R"({"k1":"v31", "k2": 300})"), STRING("$[1]")}, Null()}, // object {{STRING("[]"), STRING("$[1]")}, Null()}, // empty array - {{STRING("[123, 456]"), STRING("$[0]")}, Null()}, // int array - {{STRING("[123, 456]"), STRING("$[1]")}, Null()}, // int array + {{STRING("[123, 456]"), STRING("$[0]")}, STRING("123")}, // int array + {{STRING("[123, 456]"), STRING("$[1]")}, STRING("456")}, // int array {{STRING("[123, 456]"), STRING("$[2]")}, Null()}, // int array {{STRING(R"(["abc", "def"])"), STRING("$[0]")}, STRING("abc")}, // string array {{STRING(R"(["abc", "def"])"), STRING("$[1]")}, STRING("def")}, // string array {{STRING(R"(["abc", "def"])"), STRING("$[2]")}, Null()}, // string array {{STRING(R"([null, true, false, 100, 6.18, "abc"])"), STRING("$[0]")}, - Null()}, // multi type array + STRING("null")}, // multi type array {{STRING(R"([null, true, false, 100, 6.18, "abc"])"), STRING("$[1]")}, - Null()}, // multi type array + STRING("true")}, // multi type array {{STRING(R"([null, true, false, 100, 6.18, "abc"])"), STRING("$[2]")}, - Null()}, // multi type array + STRING("false")}, // multi type array {{STRING(R"([null, true, false, 100, 6.18, "abc"])"), STRING("$[3]")}, - Null()}, // multi type array + STRING("100")}, // multi type array {{STRING(R"([null, true, false, 100, 6.18, "abc"])"), STRING("$[4]")}, - Null()}, // multi type array + STRING("6.18")}, // multi type array {{STRING(R"([null, true, false, 100, 6.18, "abc"])"), STRING("$[5]")}, STRING("abc")}, // multi type array {{STRING(R"([null, true, false, 100, 6.18, "abc"])"), STRING("$[6]")}, Null()}, // multi type array {{STRING(R"([{"k1":"v41", "k2": 400}, 1, "a", 3.14])"), STRING("$[0]")}, - Null()}, // complex array + STRING(R"({"k1":"v41","k2":400})")}, // complex array {{STRING(R"([{"k1":"v41", "k2": 400}, 1, "a", 3.14])"), STRING("$[1]")}, - Null()}, // complex array + STRING("1")}, // complex array {{STRING(R"([{"k1":"v41", "k2": 400}, 1, "a", 3.14])"), STRING("$[2]")}, STRING("a")}, // complex array {{STRING(R"([{"k1":"v41", "k2": 400}, 1, "a", 3.14])"), STRING("$[3]")}, - Null()}, // complex array + STRING("3.14")}, // complex array {{STRING(R"([{"k1":"v41", "k2": 400}, 1, "a", 3.14])"), STRING("$[4]")}, Null()}, // complex array }; diff --git a/docs/en/docs/sql-manual/sql-functions/json-functions/jsonb_tutorial.md b/docs/en/docs/sql-manual/sql-functions/json-functions/jsonb_tutorial.md deleted file mode 100644 index 8d45b036bf..0000000000 --- a/docs/en/docs/sql-manual/sql-functions/json-functions/jsonb_tutorial.md +++ /dev/null @@ -1,801 +0,0 @@ ---- -{ - "title": "jsonb tutorial", - "language": "en" -} ---- - - - - -## jsonb tutorial - -### description - -A tutorial for JSONB datatype including create table, load data and query. -### create database and table - -``` -CREATE DATABASE testdb; - -USE testdb; - -CREATE TABLE test_jsonb ( - id INT, - j JSONB -) -DUPLICATE KEY(id) -DISTRIBUTED BY HASH(id) BUCKETS 10 -PROPERTIES("replication_num" = "1"); -``` - -### Load data - -#### stream load test_jsonb.csv test data - -- there are 2 columns, the 1st column is id and the 2nd column is json string -- there are 25 rows, the first 18 rows are valid json and the last 7 rows are invalid - - -``` -1 \N -2 null -3 true -4 false -5 100 -6 10000 -7 1000000000 -8 1152921504606846976 -9 6.18 -10 "abcd" -11 {} -12 {"k1":"v31", "k2": 300} -13 [] -14 [123, 456] -15 ["abc", "def"] -16 [null, true, false, 100, 6.18, "abc"] -17 [{"k1":"v41", "k2": 400}, 1, "a", 3.14] -18 {"k1":"v31", "k2": 300, "a1": [{"k1":"v41", "k2": 400}, 1, "a", 3.14]} -19 '' -20 'abc' -21 abc -22 100x -23 6.a8 -24 {x -25 [123, abc] -``` - -- due to the 28% of rows is invalid,stream load with default configuration will fail with error message "too many filtered rows" - -``` -curl --location-trusted -u root: -T test_jsonb.csv http://127.0.0.1:8840/api/testdb/test_jsonb/_stream_load -{ - "TxnId": 12019, - "Label": "744d9821-9c9f-43dc-bf3b-7ab048f14e32", - "TwoPhaseCommit": "false", - "Status": "Fail", - "Message": "too many filtered rows", - "NumberTotalRows": 25, - "NumberLoadedRows": 18, - "NumberFilteredRows": 7, - "NumberUnselectedRows": 0, - "LoadBytes": 380, - "LoadTimeMs": 48, - "BeginTxnTimeMs": 0, - "StreamLoadPutTimeMs": 1, - "ReadDataTimeMs": 0, - "WriteDataTimeMs": 45, - "CommitAndPublishTimeMs": 0, - "ErrorURL": "http://172.21.0.5:8840/api/_load_error_log?file=__shard_2/error_log_insert_stmt_95435c4bf5f156df-426735082a9296af_95435c4bf5f156df_426735082a9296af" -} -``` - -- stream load will success after set header configuration 'max_filter_ratio: 0.3' -``` -curl --location-trusted -u root: -H 'max_filter_ratio: 0.3' -T test_jsonb.csv http://127.0.0.1:8840/api/testdb/test_jsonb/_stream_load -{ - "TxnId": 12017, - "Label": "f37a50c1-43e9-4f4e-a159-a3db6abe2579", - "TwoPhaseCommit": "false", - "Status": "Success", - "Message": "OK", - "NumberTotalRows": 25, - "NumberLoadedRows": 18, - "NumberFilteredRows": 7, - "NumberUnselectedRows": 0, - "LoadBytes": 380, - "LoadTimeMs": 68, - "BeginTxnTimeMs": 0, - "StreamLoadPutTimeMs": 2, - "ReadDataTimeMs": 0, - "WriteDataTimeMs": 45, - "CommitAndPublishTimeMs": 19, - "ErrorURL": "http://172.21.0.5:8840/api/_load_error_log?file=__shard_0/error_log_insert_stmt_a1463f98a7b15caf-c79399b920f5bfa3_a1463f98a7b15caf_c79399b920f5bfa3" -} -``` - -- use SELECT to view the data loaded by stream load. The column with JSONB type will be displayed as plain JSON string. - -``` -mysql> SELECT * FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+ -| id | j | -+------+---------------------------------------------------------------+ -| 1 | NULL | -| 2 | null | -| 3 | true | -| 4 | false | -| 5 | 100 | -| 6 | 10000 | -| 7 | 1000000000 | -| 8 | 1152921504606846976 | -| 9 | 6.18 | -| 10 | "abcd" | -| 11 | {} | -| 12 | {"k1":"v31","k2":300} | -| 13 | [] | -| 14 | [123,456] | -| 15 | ["abc","def"] | -| 16 | [null,true,false,100,6.18,"abc"] | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | -+------+---------------------------------------------------------------+ -18 rows in set (0.03 sec) - -``` - -#### write data using insert into - -- total rows increae from 18 to 19 after insert 1 row -``` -mysql> INSERT INTO test_jsonb VALUES(26, '{"k1":"v1", "k2": 200}'); -Query OK, 1 row affected (0.09 sec) -{'label':'insert_4ece6769d1b42fd_ac9f25b3b8f3dc02', 'status':'VISIBLE', 'txnId':'12016'} - -mysql> SELECT * FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+ -| id | j | -+------+---------------------------------------------------------------+ -| 1 | NULL | -| 2 | null | -| 3 | true | -| 4 | false | -| 5 | 100 | -| 6 | 10000 | -| 7 | 1000000000 | -| 8 | 1152921504606846976 | -| 9 | 6.18 | -| 10 | "abcd" | -| 11 | {} | -| 12 | {"k1":"v31","k2":300} | -| 13 | [] | -| 14 | [123,456] | -| 15 | ["abc","def"] | -| 16 | [null,true,false,100,6.18,"abc"] | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | -| 26 | {"k1":"v1","k2":200} | -+------+---------------------------------------------------------------+ -19 rows in set (0.03 sec) - -``` - -### Query - -#### extract some filed from json by jsonb_extract functions - -1. extract the whole json, '$' stands for root in json path -``` -+------+---------------------------------------------------------------+---------------------------------------------------------------+ -| id | j | jsonb_extract(`j`, '$') | -+------+---------------------------------------------------------------+---------------------------------------------------------------+ -| 1 | NULL | NULL | -| 2 | null | null | -| 3 | true | true | -| 4 | false | false | -| 5 | 100 | 100 | -| 6 | 10000 | 10000 | -| 7 | 1000000000 | 1000000000 | -| 8 | 1152921504606846976 | 1152921504606846976 | -| 9 | 6.18 | 6.18 | -| 10 | "abcd" | "abcd" | -| 11 | {} | {} | -| 12 | {"k1":"v31","k2":300} | {"k1":"v31","k2":300} | -| 13 | [] | [] | -| 14 | [123,456] | [123,456] | -| 15 | ["abc","def"] | ["abc","def"] | -| 16 | [null,true,false,100,6.18,"abc"] | [null,true,false,100,6.18,"abc"] | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | [{"k1":"v41","k2":400},1,"a",3.14] | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | -| 26 | {"k1":"v1","k2":200} | {"k1":"v1","k2":200} | -+------+---------------------------------------------------------------+---------------------------------------------------------------+ -19 rows in set (0.03 sec) -``` - -1. extract k1 field, return NULL if it does not exist -``` -mysql> SELECT id, j, jsonb_extract(j, '$.k1') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+----------------------------+ -| id | j | jsonb_extract(`j`, '$.k1') | -+------+---------------------------------------------------------------+----------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | "v31" | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | "v31" | -| 26 | {"k1":"v1","k2":200} | "v1" | -+------+---------------------------------------------------------------+----------------------------+ -19 rows in set (0.03 sec) -``` - -1. extract element 0 of the top level array -``` -mysql> SELECT id, j, jsonb_extract(j, '$[0]') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+----------------------------+ -| id | j | jsonb_extract(`j`, '$[0]') | -+------+---------------------------------------------------------------+----------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | 123 | -| 15 | ["abc","def"] | "abc" | -| 16 | [null,true,false,100,6.18,"abc"] | null | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | {"k1":"v41","k2":400} | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+----------------------------+ -19 rows in set (0.03 sec) -``` - -1. extract a whole json array of name a1 -``` -mysql> SELECT id, j, jsonb_extract(j, '$.a1') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+------------------------------------+ -| id | j | jsonb_extract(`j`, '$.a1') | -+------+---------------------------------------------------------------+------------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | [{"k1":"v41","k2":400},1,"a",3.14] | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+------------------------------------+ -19 rows in set (0.02 sec) -``` - -1. extract nested field from an object in an array -``` -mysql> SELECT id, j, jsonb_extract(j, '$.a1[0]'), jsonb_extract(j, '$.a1[0].k1') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+-------------------------------+----------------------------------+ -| id | j | jsonb_extract(`j`, '$.a1[0]') | jsonb_extract(`j`, '$.a1[0].k1') | -+------+---------------------------------------------------------------+-------------------------------+----------------------------------+ -| 1 | NULL | NULL | NULL | -| 2 | null | NULL | NULL | -| 3 | true | NULL | NULL | -| 4 | false | NULL | NULL | -| 5 | 100 | NULL | NULL | -| 6 | 10000 | NULL | NULL | -| 7 | 1000000000 | NULL | NULL | -| 8 | 1152921504606846976 | NULL | NULL | -| 9 | 6.18 | NULL | NULL | -| 10 | "abcd" | NULL | NULL | -| 11 | {} | NULL | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | NULL | -| 13 | [] | NULL | NULL | -| 14 | [123,456] | NULL | NULL | -| 15 | ["abc","def"] | NULL | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | {"k1":"v41","k2":400} | "v41" | -| 26 | {"k1":"v1","k2":200} | NULL | NULL | -+------+---------------------------------------------------------------+-------------------------------+----------------------------------+ -19 rows in set (0.02 sec) - -``` - -1. extract field with specific datatype -- jsonb_extract_string will extract field with string type,return NULL if the field is not string -``` -mysql> SELECT id, j, jsonb_extract_string(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_extract_string(`j`, '$') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | abcd | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.02 sec) - -mysql> SELECT id, j, jsonb_extract_string(j, '$.k1') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+-----------------------------------+ -| id | j | jsonb_extract_string(`j`, '$.k1') | -+------+---------------------------------------------------------------+-----------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | v31 | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | v31 | -| 26 | {"k1":"v1","k2":200} | v1 | -+------+---------------------------------------------------------------+-----------------------------------+ -19 rows in set (0.03 sec) - -``` - -- jsonb_extract_int will extract field with int type,return NULL if the field is not int -``` -mysql> SELECT id, j, jsonb_extract_int(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+-----------------------------+ -| id | j | jsonb_extract_int(`j`, '$') | -+------+---------------------------------------------------------------+-----------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | 100 | -| 6 | 10000 | 10000 | -| 7 | 1000000000 | 1000000000 | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+-----------------------------+ -19 rows in set (0.02 sec) - -mysql> SELECT id, j, jsonb_extract_int(j, '$.k2') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_extract_int(`j`, '$.k2') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | 300 | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 | -| 26 | {"k1":"v1","k2":200} | 200 | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.03 sec) -``` - -- jsonb_extract_bigint will extract field with bigint type,return NULL if the field is not bigint -``` -mysql> SELECT id, j, jsonb_extract_bigint(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_extract_bigint(`j`, '$') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | 100 | -| 6 | 10000 | 10000 | -| 7 | 1000000000 | 1000000000 | -| 8 | 1152921504606846976 | 1152921504606846976 | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.03 sec) - -mysql> SELECT id, j, jsonb_extract_bigint(j, '$.k2') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+-----------------------------------+ -| id | j | jsonb_extract_bigint(`j`, '$.k2') | -+------+---------------------------------------------------------------+-----------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | 300 | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 | -| 26 | {"k1":"v1","k2":200} | 200 | -+------+---------------------------------------------------------------+-----------------------------------+ -19 rows in set (0.02 sec) - -``` - -- jsonb_extract_double will extract field with double type,return NULL if the field is not double -``` -mysql> SELECT id, j, jsonb_extract_double(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_extract_double(`j`, '$') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | 100 | -| 6 | 10000 | 10000 | -| 7 | 1000000000 | 1000000000 | -| 8 | 1152921504606846976 | 1.152921504606847e+18 | -| 9 | 6.18 | 6.18 | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.02 sec) - -mysql> SELECT id, j, jsonb_extract_double(j, '$.k2') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+-----------------------------------+ -| id | j | jsonb_extract_double(`j`, '$.k2') | -+------+---------------------------------------------------------------+-----------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | 300 | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 | -| 26 | {"k1":"v1","k2":200} | 200 | -+------+---------------------------------------------------------------+-----------------------------------+ -19 rows in set (0.03 sec) -``` - -- jsonb_extract_bool will extract field with boolean type,return NULL if the field is not boolean -``` -mysql> SELECT id, j, jsonb_extract_bool(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+------------------------------+ -| id | j | jsonb_extract_bool(`j`, '$') | -+------+---------------------------------------------------------------+------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | 1 | -| 4 | false | 0 | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+------------------------------+ -19 rows in set (0.01 sec) - -mysql> SELECT id, j, jsonb_extract_bool(j, '$[1]') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+---------------------------------+ -| id | j | jsonb_extract_bool(`j`, '$[1]') | -+------+---------------------------------------------------------------+---------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | 1 | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+---------------------------------+ -19 rows in set (0.01 sec) -``` - -- jsonb_extract_isnull will extract field with json null type,return 1 if the field is json null , else 0 -- json null is different from SQL NULL. SQL NULL stands for no value for a field, but json null stands for an field with special value null. -``` -mysql> SELECT id, j, jsonb_extract_isnull(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_extract_isnull(`j`, '$') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | 1 | -| 3 | true | 0 | -| 4 | false | 0 | -| 5 | 100 | 0 | -| 6 | 10000 | 0 | -| 7 | 1000000000 | 0 | -| 8 | 1152921504606846976 | 0 | -| 9 | 6.18 | 0 | -| 10 | "abcd" | 0 | -| 11 | {} | 0 | -| 12 | {"k1":"v31","k2":300} | 0 | -| 13 | [] | 0 | -| 14 | [123,456] | 0 | -| 15 | ["abc","def"] | 0 | -| 16 | [null,true,false,100,6.18,"abc"] | 0 | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 0 | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 0 | -| 26 | {"k1":"v1","k2":200} | 0 | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.03 sec) - -``` - -#### check if a field is existed in json by jsonb_exists_path - -``` -mysql> SELECT id, j, jsonb_exists_path(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+-----------------------------+ -| id | j | jsonb_exists_path(`j`, '$') | -+------+---------------------------------------------------------------+-----------------------------+ -| 1 | NULL | NULL | -| 2 | null | 1 | -| 3 | true | 1 | -| 4 | false | 1 | -| 5 | 100 | 1 | -| 6 | 10000 | 1 | -| 7 | 1000000000 | 1 | -| 8 | 1152921504606846976 | 1 | -| 9 | 6.18 | 1 | -| 10 | "abcd" | 1 | -| 11 | {} | 1 | -| 12 | {"k1":"v31","k2":300} | 1 | -| 13 | [] | 1 | -| 14 | [123,456] | 1 | -| 15 | ["abc","def"] | 1 | -| 16 | [null,true,false,100,6.18,"abc"] | 1 | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 1 | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 1 | -| 26 | {"k1":"v1","k2":200} | 1 | -+------+---------------------------------------------------------------+-----------------------------+ -19 rows in set (0.02 sec) - -mysql> SELECT id, j, jsonb_exists_path(j, '$.k1') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_exists_path(`j`, '$.k1') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | 0 | -| 3 | true | 0 | -| 4 | false | 0 | -| 5 | 100 | 0 | -| 6 | 10000 | 0 | -| 7 | 1000000000 | 0 | -| 8 | 1152921504606846976 | 0 | -| 9 | 6.18 | 0 | -| 10 | "abcd" | 0 | -| 11 | {} | 0 | -| 12 | {"k1":"v31","k2":300} | 1 | -| 13 | [] | 0 | -| 14 | [123,456] | 0 | -| 15 | ["abc","def"] | 0 | -| 16 | [null,true,false,100,6.18,"abc"] | 0 | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 0 | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 1 | -| 26 | {"k1":"v1","k2":200} | 1 | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.03 sec) - -mysql> SELECT id, j, jsonb_exists_path(j, '$[2]') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_exists_path(`j`, '$[2]') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | 0 | -| 3 | true | 0 | -| 4 | false | 0 | -| 5 | 100 | 0 | -| 6 | 10000 | 0 | -| 7 | 1000000000 | 0 | -| 8 | 1152921504606846976 | 0 | -| 9 | 6.18 | 0 | -| 10 | "abcd" | 0 | -| 11 | {} | 0 | -| 12 | {"k1":"v31","k2":300} | 0 | -| 13 | [] | 0 | -| 14 | [123,456] | 0 | -| 15 | ["abc","def"] | 0 | -| 16 | [null,true,false,100,6.18,"abc"] | 1 | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 1 | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 0 | -| 26 | {"k1":"v1","k2":200} | 0 | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.02 sec) - - -``` - -#### get the datatype of a field in json by jsonb_type - -- return the data type of the field specified by json path, NULL if not existed. -``` -mysql> SELECT id, j, jsonb_type(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+----------------------+ -| id | j | jsonb_type(`j`, '$') | -+------+---------------------------------------------------------------+----------------------+ -| 1 | NULL | NULL | -| 2 | null | null | -| 3 | true | bool | -| 4 | false | bool | -| 5 | 100 | int | -| 6 | 10000 | int | -| 7 | 1000000000 | int | -| 8 | 1152921504606846976 | bigint | -| 9 | 6.18 | double | -| 10 | "abcd" | string | -| 11 | {} | object | -| 12 | {"k1":"v31","k2":300} | object | -| 13 | [] | array | -| 14 | [123,456] | array | -| 15 | ["abc","def"] | array | -| 16 | [null,true,false,100,6.18,"abc"] | array | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | array | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | object | -| 26 | {"k1":"v1","k2":200} | object | -+------+---------------------------------------------------------------+----------------------+ -19 rows in set (0.02 sec) - -mysql> select id, j, jsonb_type(j, '$.k1') from test_jsonb order by id; -+------+---------------------------------------------------------------+-------------------------+ -| id | j | jsonb_type(`j`, '$.k1') | -+------+---------------------------------------------------------------+-------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | string | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | string | -| 26 | {"k1":"v1","k2":200} | string | -+------+---------------------------------------------------------------+-------------------------+ -19 rows in set (0.03 sec) - -``` - -### keywords -JSONB, JSON, jsonb_parse, jsonb_parse_error_to_null, jsonb_parse_error_to_value, jsonb_extract, jsonb_extract_isnull, jsonb_extract_bool, jsonb_extract_int, jsonb_extract_bigint, jsonb_extract_double, jsonb_extract_string, jsonb_exists_path, jsonb_type diff --git a/docs/en/docs/sql-manual/sql-reference/Data-Types/JSONB.md b/docs/en/docs/sql-manual/sql-reference/Data-Types/JSONB.md index 07b37c45c2..4ba06b1593 100644 --- a/docs/en/docs/sql-manual/sql-reference/Data-Types/JSONB.md +++ b/docs/en/docs/sql-manual/sql-reference/Data-Types/JSONB.md @@ -35,8 +35,775 @@ under the License. 2. JSONB format is more efficient. Using jsonb_extract functions on JSONB format is 2-4 times faster than get_json_xx on JSON STRING format. ### example - refer to jsob tutorial. +A tutorial for JSONB datatype including create table, load data and query. + +#### create database and table + +``` +CREATE DATABASE testdb; + +USE testdb; + +CREATE TABLE test_jsonb ( + id INT, + j JSONB +) +DUPLICATE KEY(id) +DISTRIBUTED BY HASH(id) BUCKETS 10 +PROPERTIES("replication_num" = "1"); +``` + +#### Load data + +##### stream load test_jsonb.csv test data + +- there are 2 columns, the 1st column is id and the 2nd column is json string +- there are 25 rows, the first 18 rows are valid json and the last 7 rows are invalid + + +``` +1 \N +2 null +3 true +4 false +5 100 +6 10000 +7 1000000000 +8 1152921504606846976 +9 6.18 +10 "abcd" +11 {} +12 {"k1":"v31", "k2": 300} +13 [] +14 [123, 456] +15 ["abc", "def"] +16 [null, true, false, 100, 6.18, "abc"] +17 [{"k1":"v41", "k2": 400}, 1, "a", 3.14] +18 {"k1":"v31", "k2": 300, "a1": [{"k1":"v41", "k2": 400}, 1, "a", 3.14]} +19 '' +20 'abc' +21 abc +22 100x +23 6.a8 +24 {x +25 [123, abc] +``` + +- due to the 28% of rows is invalid,stream load with default configuration will fail with error message "too many filtered rows" + +``` +curl --location-trusted -u root: -T test_jsonb.csv http://127.0.0.1:8840/api/testdb/test_jsonb/_stream_load +{ + "TxnId": 12019, + "Label": "744d9821-9c9f-43dc-bf3b-7ab048f14e32", + "TwoPhaseCommit": "false", + "Status": "Fail", + "Message": "too many filtered rows", + "NumberTotalRows": 25, + "NumberLoadedRows": 18, + "NumberFilteredRows": 7, + "NumberUnselectedRows": 0, + "LoadBytes": 380, + "LoadTimeMs": 48, + "BeginTxnTimeMs": 0, + "StreamLoadPutTimeMs": 1, + "ReadDataTimeMs": 0, + "WriteDataTimeMs": 45, + "CommitAndPublishTimeMs": 0, + "ErrorURL": "http://172.21.0.5:8840/api/_load_error_log?file=__shard_2/error_log_insert_stmt_95435c4bf5f156df-426735082a9296af_95435c4bf5f156df_426735082a9296af" +} +``` + +- stream load will success after set header configuration 'max_filter_ratio: 0.3' +``` +curl --location-trusted -u root: -H 'max_filter_ratio: 0.3' -T test_jsonb.csv http://127.0.0.1:8840/api/testdb/test_jsonb/_stream_load +{ + "TxnId": 12017, + "Label": "f37a50c1-43e9-4f4e-a159-a3db6abe2579", + "TwoPhaseCommit": "false", + "Status": "Success", + "Message": "OK", + "NumberTotalRows": 25, + "NumberLoadedRows": 18, + "NumberFilteredRows": 7, + "NumberUnselectedRows": 0, + "LoadBytes": 380, + "LoadTimeMs": 68, + "BeginTxnTimeMs": 0, + "StreamLoadPutTimeMs": 2, + "ReadDataTimeMs": 0, + "WriteDataTimeMs": 45, + "CommitAndPublishTimeMs": 19, + "ErrorURL": "http://172.21.0.5:8840/api/_load_error_log?file=__shard_0/error_log_insert_stmt_a1463f98a7b15caf-c79399b920f5bfa3_a1463f98a7b15caf_c79399b920f5bfa3" +} +``` + +- use SELECT to view the data loaded by stream load. The column with JSONB type will be displayed as plain JSON string. + +``` +mysql> SELECT * FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+ +| id | j | ++------+---------------------------------------------------------------+ +| 1 | NULL | +| 2 | null | +| 3 | true | +| 4 | false | +| 5 | 100 | +| 6 | 10000 | +| 7 | 1000000000 | +| 8 | 1152921504606846976 | +| 9 | 6.18 | +| 10 | "abcd" | +| 11 | {} | +| 12 | {"k1":"v31","k2":300} | +| 13 | [] | +| 14 | [123,456] | +| 15 | ["abc","def"] | +| 16 | [null,true,false,100,6.18,"abc"] | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | ++------+---------------------------------------------------------------+ +18 rows in set (0.03 sec) + +``` + +##### write data using insert into + +- total rows increae from 18 to 19 after insert 1 row +``` +mysql> INSERT INTO test_jsonb VALUES(26, '{"k1":"v1", "k2": 200}'); +Query OK, 1 row affected (0.09 sec) +{'label':'insert_4ece6769d1b42fd_ac9f25b3b8f3dc02', 'status':'VISIBLE', 'txnId':'12016'} + +mysql> SELECT * FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+ +| id | j | ++------+---------------------------------------------------------------+ +| 1 | NULL | +| 2 | null | +| 3 | true | +| 4 | false | +| 5 | 100 | +| 6 | 10000 | +| 7 | 1000000000 | +| 8 | 1152921504606846976 | +| 9 | 6.18 | +| 10 | "abcd" | +| 11 | {} | +| 12 | {"k1":"v31","k2":300} | +| 13 | [] | +| 14 | [123,456] | +| 15 | ["abc","def"] | +| 16 | [null,true,false,100,6.18,"abc"] | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | +| 26 | {"k1":"v1","k2":200} | ++------+---------------------------------------------------------------+ +19 rows in set (0.03 sec) + +``` + +#### Query + +##### extract some filed from json by jsonb_extract functions + +1. extract the whole json, '$' stands for root in json path +``` ++------+---------------------------------------------------------------+---------------------------------------------------------------+ +| id | j | jsonb_extract(`j`, '$') | ++------+---------------------------------------------------------------+---------------------------------------------------------------+ +| 1 | NULL | NULL | +| 2 | null | null | +| 3 | true | true | +| 4 | false | false | +| 5 | 100 | 100 | +| 6 | 10000 | 10000 | +| 7 | 1000000000 | 1000000000 | +| 8 | 1152921504606846976 | 1152921504606846976 | +| 9 | 6.18 | 6.18 | +| 10 | "abcd" | "abcd" | +| 11 | {} | {} | +| 12 | {"k1":"v31","k2":300} | {"k1":"v31","k2":300} | +| 13 | [] | [] | +| 14 | [123,456] | [123,456] | +| 15 | ["abc","def"] | ["abc","def"] | +| 16 | [null,true,false,100,6.18,"abc"] | [null,true,false,100,6.18,"abc"] | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | [{"k1":"v41","k2":400},1,"a",3.14] | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | +| 26 | {"k1":"v1","k2":200} | {"k1":"v1","k2":200} | ++------+---------------------------------------------------------------+---------------------------------------------------------------+ +19 rows in set (0.03 sec) +``` + +1. extract k1 field, return NULL if it does not exist +``` +mysql> SELECT id, j, jsonb_extract(j, '$.k1') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+----------------------------+ +| id | j | jsonb_extract(`j`, '$.k1') | ++------+---------------------------------------------------------------+----------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | "v31" | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | "v31" | +| 26 | {"k1":"v1","k2":200} | "v1" | ++------+---------------------------------------------------------------+----------------------------+ +19 rows in set (0.03 sec) +``` + +1. extract element 0 of the top level array +``` +mysql> SELECT id, j, jsonb_extract(j, '$[0]') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+----------------------------+ +| id | j | jsonb_extract(`j`, '$[0]') | ++------+---------------------------------------------------------------+----------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | 123 | +| 15 | ["abc","def"] | "abc" | +| 16 | [null,true,false,100,6.18,"abc"] | null | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | {"k1":"v41","k2":400} | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+----------------------------+ +19 rows in set (0.03 sec) +``` + +1. extract a whole json array of name a1 +``` +mysql> SELECT id, j, jsonb_extract(j, '$.a1') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+------------------------------------+ +| id | j | jsonb_extract(`j`, '$.a1') | ++------+---------------------------------------------------------------+------------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | [{"k1":"v41","k2":400},1,"a",3.14] | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+------------------------------------+ +19 rows in set (0.02 sec) +``` + +1. extract nested field from an object in an array +``` +mysql> SELECT id, j, jsonb_extract(j, '$.a1[0]'), jsonb_extract(j, '$.a1[0].k1') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+-------------------------------+----------------------------------+ +| id | j | jsonb_extract(`j`, '$.a1[0]') | jsonb_extract(`j`, '$.a1[0].k1') | ++------+---------------------------------------------------------------+-------------------------------+----------------------------------+ +| 1 | NULL | NULL | NULL | +| 2 | null | NULL | NULL | +| 3 | true | NULL | NULL | +| 4 | false | NULL | NULL | +| 5 | 100 | NULL | NULL | +| 6 | 10000 | NULL | NULL | +| 7 | 1000000000 | NULL | NULL | +| 8 | 1152921504606846976 | NULL | NULL | +| 9 | 6.18 | NULL | NULL | +| 10 | "abcd" | NULL | NULL | +| 11 | {} | NULL | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | NULL | +| 13 | [] | NULL | NULL | +| 14 | [123,456] | NULL | NULL | +| 15 | ["abc","def"] | NULL | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | {"k1":"v41","k2":400} | "v41" | +| 26 | {"k1":"v1","k2":200} | NULL | NULL | ++------+---------------------------------------------------------------+-------------------------------+----------------------------------+ +19 rows in set (0.02 sec) + +``` + +1. extract field with specific datatype +- jsonb_extract_string will extract field with string type,convert to string if the field is not string +``` +mysql> SELECT id, j, jsonb_extract_string(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+---------------------------------------------------------------+ +| id | j | jsonb_extract_string(`j`, '$') | ++------+---------------------------------------------------------------+---------------------------------------------------------------+ +| 1 | NULL | NULL | +| 2 | null | null | +| 3 | true | true | +| 4 | false | false | +| 5 | 100 | 100 | +| 6 | 10000 | 10000 | +| 7 | 1000000000 | 1000000000 | +| 8 | 1152921504606846976 | 1152921504606846976 | +| 9 | 6.18 | 6.18 | +| 10 | "abcd" | abcd | +| 11 | {} | {} | +| 12 | {"k1":"v31","k2":300} | {"k1":"v31","k2":300} | +| 13 | [] | [] | +| 14 | [123,456] | [123,456] | +| 15 | ["abc","def"] | ["abc","def"] | +| 16 | [null,true,false,100,6.18,"abc"] | [null,true,false,100,6.18,"abc"] | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | [{"k1":"v41","k2":400},1,"a",3.14] | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | +| 26 | {"k1":"v1","k2":200} | {"k1":"v1","k2":200} | ++------+---------------------------------------------------------------+---------------------------------------------------------------+ +19 rows in set (0.02 sec) + +mysql> SELECT id, j, jsonb_extract_string(j, '$.k1') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+-----------------------------------+ +| id | j | jsonb_extract_string(`j`, '$.k1') | ++------+---------------------------------------------------------------+-----------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | v31 | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | v31 | +| 26 | {"k1":"v1","k2":200} | v1 | ++------+---------------------------------------------------------------+-----------------------------------+ +19 rows in set (0.03 sec) + +``` + +- jsonb_extract_int will extract field with int type,return NULL if the field is not int +``` +mysql> SELECT id, j, jsonb_extract_int(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+-----------------------------+ +| id | j | jsonb_extract_int(`j`, '$') | ++------+---------------------------------------------------------------+-----------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | 100 | +| 6 | 10000 | 10000 | +| 7 | 1000000000 | 1000000000 | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+-----------------------------+ +19 rows in set (0.02 sec) + +mysql> SELECT id, j, jsonb_extract_int(j, '$.k2') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+--------------------------------+ +| id | j | jsonb_extract_int(`j`, '$.k2') | ++------+---------------------------------------------------------------+--------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | 300 | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 | +| 26 | {"k1":"v1","k2":200} | 200 | ++------+---------------------------------------------------------------+--------------------------------+ +19 rows in set (0.03 sec) +``` + +- jsonb_extract_bigint will extract field with bigint type,return NULL if the field is not bigint +``` +mysql> SELECT id, j, jsonb_extract_bigint(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+--------------------------------+ +| id | j | jsonb_extract_bigint(`j`, '$') | ++------+---------------------------------------------------------------+--------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | 100 | +| 6 | 10000 | 10000 | +| 7 | 1000000000 | 1000000000 | +| 8 | 1152921504606846976 | 1152921504606846976 | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+--------------------------------+ +19 rows in set (0.03 sec) + +mysql> SELECT id, j, jsonb_extract_bigint(j, '$.k2') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+-----------------------------------+ +| id | j | jsonb_extract_bigint(`j`, '$.k2') | ++------+---------------------------------------------------------------+-----------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | 300 | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 | +| 26 | {"k1":"v1","k2":200} | 200 | ++------+---------------------------------------------------------------+-----------------------------------+ +19 rows in set (0.02 sec) + +``` + +- jsonb_extract_double will extract field with double type,return NULL if the field is not double +``` +mysql> SELECT id, j, jsonb_extract_double(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+--------------------------------+ +| id | j | jsonb_extract_double(`j`, '$') | ++------+---------------------------------------------------------------+--------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | 100 | +| 6 | 10000 | 10000 | +| 7 | 1000000000 | 1000000000 | +| 8 | 1152921504606846976 | 1.152921504606847e+18 | +| 9 | 6.18 | 6.18 | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+--------------------------------+ +19 rows in set (0.02 sec) + +mysql> SELECT id, j, jsonb_extract_double(j, '$.k2') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+-----------------------------------+ +| id | j | jsonb_extract_double(`j`, '$.k2') | ++------+---------------------------------------------------------------+-----------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | 300 | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 | +| 26 | {"k1":"v1","k2":200} | 200 | ++------+---------------------------------------------------------------+-----------------------------------+ +19 rows in set (0.03 sec) +``` + +- jsonb_extract_bool will extract field with boolean type,return NULL if the field is not boolean +``` +mysql> SELECT id, j, jsonb_extract_bool(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+------------------------------+ +| id | j | jsonb_extract_bool(`j`, '$') | ++------+---------------------------------------------------------------+------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | 1 | +| 4 | false | 0 | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+------------------------------+ +19 rows in set (0.01 sec) + +mysql> SELECT id, j, jsonb_extract_bool(j, '$[1]') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+---------------------------------+ +| id | j | jsonb_extract_bool(`j`, '$[1]') | ++------+---------------------------------------------------------------+---------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | 1 | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+---------------------------------+ +19 rows in set (0.01 sec) +``` + +- jsonb_extract_isnull will extract field with json null type,return 1 if the field is json null , else 0 +- json null is different from SQL NULL. SQL NULL stands for no value for a field, but json null stands for an field with special value null. +``` +mysql> SELECT id, j, jsonb_extract_isnull(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+--------------------------------+ +| id | j | jsonb_extract_isnull(`j`, '$') | ++------+---------------------------------------------------------------+--------------------------------+ +| 1 | NULL | NULL | +| 2 | null | 1 | +| 3 | true | 0 | +| 4 | false | 0 | +| 5 | 100 | 0 | +| 6 | 10000 | 0 | +| 7 | 1000000000 | 0 | +| 8 | 1152921504606846976 | 0 | +| 9 | 6.18 | 0 | +| 10 | "abcd" | 0 | +| 11 | {} | 0 | +| 12 | {"k1":"v31","k2":300} | 0 | +| 13 | [] | 0 | +| 14 | [123,456] | 0 | +| 15 | ["abc","def"] | 0 | +| 16 | [null,true,false,100,6.18,"abc"] | 0 | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 0 | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 0 | +| 26 | {"k1":"v1","k2":200} | 0 | ++------+---------------------------------------------------------------+--------------------------------+ +19 rows in set (0.03 sec) + +``` + +##### check if a field is existed in json by jsonb_exists_path + +``` +mysql> SELECT id, j, jsonb_exists_path(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+-----------------------------+ +| id | j | jsonb_exists_path(`j`, '$') | ++------+---------------------------------------------------------------+-----------------------------+ +| 1 | NULL | NULL | +| 2 | null | 1 | +| 3 | true | 1 | +| 4 | false | 1 | +| 5 | 100 | 1 | +| 6 | 10000 | 1 | +| 7 | 1000000000 | 1 | +| 8 | 1152921504606846976 | 1 | +| 9 | 6.18 | 1 | +| 10 | "abcd" | 1 | +| 11 | {} | 1 | +| 12 | {"k1":"v31","k2":300} | 1 | +| 13 | [] | 1 | +| 14 | [123,456] | 1 | +| 15 | ["abc","def"] | 1 | +| 16 | [null,true,false,100,6.18,"abc"] | 1 | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 1 | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 1 | +| 26 | {"k1":"v1","k2":200} | 1 | ++------+---------------------------------------------------------------+-----------------------------+ +19 rows in set (0.02 sec) + +mysql> SELECT id, j, jsonb_exists_path(j, '$.k1') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+--------------------------------+ +| id | j | jsonb_exists_path(`j`, '$.k1') | ++------+---------------------------------------------------------------+--------------------------------+ +| 1 | NULL | NULL | +| 2 | null | 0 | +| 3 | true | 0 | +| 4 | false | 0 | +| 5 | 100 | 0 | +| 6 | 10000 | 0 | +| 7 | 1000000000 | 0 | +| 8 | 1152921504606846976 | 0 | +| 9 | 6.18 | 0 | +| 10 | "abcd" | 0 | +| 11 | {} | 0 | +| 12 | {"k1":"v31","k2":300} | 1 | +| 13 | [] | 0 | +| 14 | [123,456] | 0 | +| 15 | ["abc","def"] | 0 | +| 16 | [null,true,false,100,6.18,"abc"] | 0 | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 0 | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 1 | +| 26 | {"k1":"v1","k2":200} | 1 | ++------+---------------------------------------------------------------+--------------------------------+ +19 rows in set (0.03 sec) + +mysql> SELECT id, j, jsonb_exists_path(j, '$[2]') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+--------------------------------+ +| id | j | jsonb_exists_path(`j`, '$[2]') | ++------+---------------------------------------------------------------+--------------------------------+ +| 1 | NULL | NULL | +| 2 | null | 0 | +| 3 | true | 0 | +| 4 | false | 0 | +| 5 | 100 | 0 | +| 6 | 10000 | 0 | +| 7 | 1000000000 | 0 | +| 8 | 1152921504606846976 | 0 | +| 9 | 6.18 | 0 | +| 10 | "abcd" | 0 | +| 11 | {} | 0 | +| 12 | {"k1":"v31","k2":300} | 0 | +| 13 | [] | 0 | +| 14 | [123,456] | 0 | +| 15 | ["abc","def"] | 0 | +| 16 | [null,true,false,100,6.18,"abc"] | 1 | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 1 | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 0 | +| 26 | {"k1":"v1","k2":200} | 0 | ++------+---------------------------------------------------------------+--------------------------------+ +19 rows in set (0.02 sec) + + +``` + +##### get the datatype of a field in json by jsonb_type + +- return the data type of the field specified by json path, NULL if not existed. +``` +mysql> SELECT id, j, jsonb_type(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+----------------------+ +| id | j | jsonb_type(`j`, '$') | ++------+---------------------------------------------------------------+----------------------+ +| 1 | NULL | NULL | +| 2 | null | null | +| 3 | true | bool | +| 4 | false | bool | +| 5 | 100 | int | +| 6 | 10000 | int | +| 7 | 1000000000 | int | +| 8 | 1152921504606846976 | bigint | +| 9 | 6.18 | double | +| 10 | "abcd" | string | +| 11 | {} | object | +| 12 | {"k1":"v31","k2":300} | object | +| 13 | [] | array | +| 14 | [123,456] | array | +| 15 | ["abc","def"] | array | +| 16 | [null,true,false,100,6.18,"abc"] | array | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | array | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | object | +| 26 | {"k1":"v1","k2":200} | object | ++------+---------------------------------------------------------------+----------------------+ +19 rows in set (0.02 sec) + +mysql> select id, j, jsonb_type(j, '$.k1') from test_jsonb order by id; ++------+---------------------------------------------------------------+-------------------------+ +| id | j | jsonb_type(`j`, '$.k1') | ++------+---------------------------------------------------------------+-------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | string | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | string | +| 26 | {"k1":"v1","k2":200} | string | ++------+---------------------------------------------------------------+-------------------------+ +19 rows in set (0.03 sec) + +``` ### keywords +JSONB, JSON, jsonb_parse, jsonb_parse_error_to_null, jsonb_parse_error_to_value, jsonb_extract, jsonb_extract_isnull, jsonb_extract_bool, jsonb_extract_int, jsonb_extract_bigint, jsonb_extract_double, jsonb_extract_string, jsonb_exists_path, jsonb_type - JSONB JSON diff --git a/docs/sidebars.json b/docs/sidebars.json index b63ee5318c..5e01a40e25 100644 --- a/docs/sidebars.json +++ b/docs/sidebars.json @@ -547,7 +547,6 @@ "type": "category", "label": "JSON Functions", "items": [ - "sql-manual/sql-functions/json-functions/jsonb_tutorial", "sql-manual/sql-functions/json-functions/jsonb_parse", "sql-manual/sql-functions/json-functions/jsonb_extract", "sql-manual/sql-functions/json-functions/get_json_double", diff --git a/docs/zh-CN/docs/sql-manual/sql-functions/json-functions/jsonb_tutorial.md b/docs/zh-CN/docs/sql-manual/sql-functions/json-functions/jsonb_tutorial.md deleted file mode 100644 index a923228650..0000000000 --- a/docs/zh-CN/docs/sql-manual/sql-functions/json-functions/jsonb_tutorial.md +++ /dev/null @@ -1,798 +0,0 @@ ---- -{ - "title": "jsonb tutorial", - "language": "zh-CN" -} ---- - - - -## jsonb tutorial - -### description - 用一个从建表、导数据、查询全周期的例子说明JSONB数据类型的功能和用法。 - -### 创建库表 - -``` -CREATE DATABASE testdb; - -USE testdb; - -CREATE TABLE test_jsonb ( - id INT, - j JSONB -) -DUPLICATE KEY(id) -DISTRIBUTED BY HASH(id) BUCKETS 10 -PROPERTIES("replication_num" = "1"); -``` - -### 导入数据 - -#### stream load 导入test_jsonb.csv测试数据 - -- 测试数据有2列,第一列id,第二列是json -- 测试数据有25行,其中前18行的json是合法的,后7行的json是非法的 - -``` -1 \N -2 null -3 true -4 false -5 100 -6 10000 -7 1000000000 -8 1152921504606846976 -9 6.18 -10 "abcd" -11 {} -12 {"k1":"v31", "k2": 300} -13 [] -14 [123, 456] -15 ["abc", "def"] -16 [null, true, false, 100, 6.18, "abc"] -17 [{"k1":"v41", "k2": 400}, 1, "a", 3.14] -18 {"k1":"v31", "k2": 300, "a1": [{"k1":"v41", "k2": 400}, 1, "a", 3.14]} -19 '' -20 'abc' -21 abc -22 100x -23 6.a8 -24 {x -25 [123, abc] -``` - -- 由于有28%的非法数据,默认会失败报错 "too many filtered rows" -``` -curl --location-trusted -u root: -T test_jsonb.csv http://127.0.0.1:8840/api/testdb/test_jsonb/_stream_load -{ - "TxnId": 12019, - "Label": "744d9821-9c9f-43dc-bf3b-7ab048f14e32", - "TwoPhaseCommit": "false", - "Status": "Fail", - "Message": "too many filtered rows", - "NumberTotalRows": 25, - "NumberLoadedRows": 18, - "NumberFilteredRows": 7, - "NumberUnselectedRows": 0, - "LoadBytes": 380, - "LoadTimeMs": 48, - "BeginTxnTimeMs": 0, - "StreamLoadPutTimeMs": 1, - "ReadDataTimeMs": 0, - "WriteDataTimeMs": 45, - "CommitAndPublishTimeMs": 0, - "ErrorURL": "http://172.21.0.5:8840/api/_load_error_log?file=__shard_2/error_log_insert_stmt_95435c4bf5f156df-426735082a9296af_95435c4bf5f156df_426735082a9296af" -} -``` - -- 设置容错率参数 'max_filter_ratio: 0.3' -``` -curl --location-trusted -u root: -H 'max_filter_ratio: 0.3' -T test_jsonb.csv http://127.0.0.1:8840/api/testdb/test_jsonb/_stream_load -{ - "TxnId": 12017, - "Label": "f37a50c1-43e9-4f4e-a159-a3db6abe2579", - "TwoPhaseCommit": "false", - "Status": "Success", - "Message": "OK", - "NumberTotalRows": 25, - "NumberLoadedRows": 18, - "NumberFilteredRows": 7, - "NumberUnselectedRows": 0, - "LoadBytes": 380, - "LoadTimeMs": 68, - "BeginTxnTimeMs": 0, - "StreamLoadPutTimeMs": 2, - "ReadDataTimeMs": 0, - "WriteDataTimeMs": 45, - "CommitAndPublishTimeMs": 19, - "ErrorURL": "http://172.21.0.5:8840/api/_load_error_log?file=__shard_0/error_log_insert_stmt_a1463f98a7b15caf-c79399b920f5bfa3_a1463f98a7b15caf_c79399b920f5bfa3" -} -``` - -- 查看stream load导入的数据,JSONB类型的列j会自动转成JSON string展示 - -``` -mysql> SELECT * FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+ -| id | j | -+------+---------------------------------------------------------------+ -| 1 | NULL | -| 2 | null | -| 3 | true | -| 4 | false | -| 5 | 100 | -| 6 | 10000 | -| 7 | 1000000000 | -| 8 | 1152921504606846976 | -| 9 | 6.18 | -| 10 | "abcd" | -| 11 | {} | -| 12 | {"k1":"v31","k2":300} | -| 13 | [] | -| 14 | [123,456] | -| 15 | ["abc","def"] | -| 16 | [null,true,false,100,6.18,"abc"] | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | -+------+---------------------------------------------------------------+ -18 rows in set (0.03 sec) - -``` - -#### insert into 插入数据 - -- insert 1条数据,总数据从18条增加到19条 -``` -mysql> INSERT INTO test_jsonb VALUES(26, '{"k1":"v1", "k2": 200}'); -Query OK, 1 row affected (0.09 sec) -{'label':'insert_4ece6769d1b42fd_ac9f25b3b8f3dc02', 'status':'VISIBLE', 'txnId':'12016'} - -mysql> SELECT * FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+ -| id | j | -+------+---------------------------------------------------------------+ -| 1 | NULL | -| 2 | null | -| 3 | true | -| 4 | false | -| 5 | 100 | -| 6 | 10000 | -| 7 | 1000000000 | -| 8 | 1152921504606846976 | -| 9 | 6.18 | -| 10 | "abcd" | -| 11 | {} | -| 12 | {"k1":"v31","k2":300} | -| 13 | [] | -| 14 | [123,456] | -| 15 | ["abc","def"] | -| 16 | [null,true,false,100,6.18,"abc"] | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | -| 26 | {"k1":"v1","k2":200} | -+------+---------------------------------------------------------------+ -19 rows in set (0.03 sec) - -``` - -### 查询 - -#### 用jsonb_extract取json内的某个字段 - -1. 获取整个json,$ 在json path中代表root,即整个json -``` -+------+---------------------------------------------------------------+---------------------------------------------------------------+ -| id | j | jsonb_extract(`j`, '$') | -+------+---------------------------------------------------------------+---------------------------------------------------------------+ -| 1 | NULL | NULL | -| 2 | null | null | -| 3 | true | true | -| 4 | false | false | -| 5 | 100 | 100 | -| 6 | 10000 | 10000 | -| 7 | 1000000000 | 1000000000 | -| 8 | 1152921504606846976 | 1152921504606846976 | -| 9 | 6.18 | 6.18 | -| 10 | "abcd" | "abcd" | -| 11 | {} | {} | -| 12 | {"k1":"v31","k2":300} | {"k1":"v31","k2":300} | -| 13 | [] | [] | -| 14 | [123,456] | [123,456] | -| 15 | ["abc","def"] | ["abc","def"] | -| 16 | [null,true,false,100,6.18,"abc"] | [null,true,false,100,6.18,"abc"] | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | [{"k1":"v41","k2":400},1,"a",3.14] | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | -| 26 | {"k1":"v1","k2":200} | {"k1":"v1","k2":200} | -+------+---------------------------------------------------------------+---------------------------------------------------------------+ -19 rows in set (0.03 sec) -``` - -1. 获取k1字段,没有k1字段的行返回NULL -``` -mysql> SELECT id, j, jsonb_extract(j, '$.k1') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+----------------------------+ -| id | j | jsonb_extract(`j`, '$.k1') | -+------+---------------------------------------------------------------+----------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | "v31" | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | "v31" | -| 26 | {"k1":"v1","k2":200} | "v1" | -+------+---------------------------------------------------------------+----------------------------+ -19 rows in set (0.03 sec) -``` - -1. 获取顶层数组的第0个元素 -``` -mysql> SELECT id, j, jsonb_extract(j, '$[0]') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+----------------------------+ -| id | j | jsonb_extract(`j`, '$[0]') | -+------+---------------------------------------------------------------+----------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | 123 | -| 15 | ["abc","def"] | "abc" | -| 16 | [null,true,false,100,6.18,"abc"] | null | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | {"k1":"v41","k2":400} | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+----------------------------+ -19 rows in set (0.03 sec) -``` - -1. 获取整个json array -``` -mysql> SELECT id, j, jsonb_extract(j, '$.a1') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+------------------------------------+ -| id | j | jsonb_extract(`j`, '$.a1') | -+------+---------------------------------------------------------------+------------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | [{"k1":"v41","k2":400},1,"a",3.14] | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+------------------------------------+ -19 rows in set (0.02 sec) -``` - -1. 获取json array中嵌套object的字段 -``` -mysql> SELECT id, j, jsonb_extract(j, '$.a1[0]'), jsonb_extract(j, '$.a1[0].k1') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+-------------------------------+----------------------------------+ -| id | j | jsonb_extract(`j`, '$.a1[0]') | jsonb_extract(`j`, '$.a1[0].k1') | -+------+---------------------------------------------------------------+-------------------------------+----------------------------------+ -| 1 | NULL | NULL | NULL | -| 2 | null | NULL | NULL | -| 3 | true | NULL | NULL | -| 4 | false | NULL | NULL | -| 5 | 100 | NULL | NULL | -| 6 | 10000 | NULL | NULL | -| 7 | 1000000000 | NULL | NULL | -| 8 | 1152921504606846976 | NULL | NULL | -| 9 | 6.18 | NULL | NULL | -| 10 | "abcd" | NULL | NULL | -| 11 | {} | NULL | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | NULL | -| 13 | [] | NULL | NULL | -| 14 | [123,456] | NULL | NULL | -| 15 | ["abc","def"] | NULL | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | {"k1":"v41","k2":400} | "v41" | -| 26 | {"k1":"v1","k2":200} | NULL | NULL | -+------+---------------------------------------------------------------+-------------------------------+----------------------------------+ -19 rows in set (0.02 sec) - -``` - -1. 获取具体类型的 -- jsonb_extract_string 获取string类型字段,非string类型返回NULL -``` -mysql> SELECT id, j, jsonb_extract_string(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_extract_string(`j`, '$') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | abcd | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.02 sec) - -mysql> SELECT id, j, jsonb_extract_string(j, '$.k1') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+-----------------------------------+ -| id | j | jsonb_extract_string(`j`, '$.k1') | -+------+---------------------------------------------------------------+-----------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | v31 | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | v31 | -| 26 | {"k1":"v1","k2":200} | v1 | -+------+---------------------------------------------------------------+-----------------------------------+ -19 rows in set (0.03 sec) - -``` - -- jsonb_extract_int 获取int类型字段,非int类型返回NULL -``` -mysql> SELECT id, j, jsonb_extract_int(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+-----------------------------+ -| id | j | jsonb_extract_int(`j`, '$') | -+------+---------------------------------------------------------------+-----------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | 100 | -| 6 | 10000 | 10000 | -| 7 | 1000000000 | 1000000000 | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+-----------------------------+ -19 rows in set (0.02 sec) - -mysql> SELECT id, j, jsonb_extract_int(j, '$.k2') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_extract_int(`j`, '$.k2') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | 300 | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 | -| 26 | {"k1":"v1","k2":200} | 200 | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.03 sec) -``` - -- jsonb_extract_bigint 获取bigint类型字段,非bigint类型返回NULL -``` -mysql> SELECT id, j, jsonb_extract_bigint(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_extract_bigint(`j`, '$') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | 100 | -| 6 | 10000 | 10000 | -| 7 | 1000000000 | 1000000000 | -| 8 | 1152921504606846976 | 1152921504606846976 | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.03 sec) - -mysql> SELECT id, j, jsonb_extract_bigint(j, '$.k2') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+-----------------------------------+ -| id | j | jsonb_extract_bigint(`j`, '$.k2') | -+------+---------------------------------------------------------------+-----------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | 300 | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 | -| 26 | {"k1":"v1","k2":200} | 200 | -+------+---------------------------------------------------------------+-----------------------------------+ -19 rows in set (0.02 sec) - -``` - -- jsonb_extract_double 获取double类型字段,非double类型返回NULL -``` -mysql> SELECT id, j, jsonb_extract_double(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_extract_double(`j`, '$') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | 100 | -| 6 | 10000 | 10000 | -| 7 | 1000000000 | 1000000000 | -| 8 | 1152921504606846976 | 1.152921504606847e+18 | -| 9 | 6.18 | 6.18 | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.02 sec) - -mysql> SELECT id, j, jsonb_extract_double(j, '$.k2') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+-----------------------------------+ -| id | j | jsonb_extract_double(`j`, '$.k2') | -+------+---------------------------------------------------------------+-----------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | 300 | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 | -| 26 | {"k1":"v1","k2":200} | 200 | -+------+---------------------------------------------------------------+-----------------------------------+ -19 rows in set (0.03 sec) -``` - -- jsonb_extract_bool 获取bool类型字段,非bool类型返回NULL -``` -mysql> SELECT id, j, jsonb_extract_bool(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+------------------------------+ -| id | j | jsonb_extract_bool(`j`, '$') | -+------+---------------------------------------------------------------+------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | 1 | -| 4 | false | 0 | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+------------------------------+ -19 rows in set (0.01 sec) - -mysql> SELECT id, j, jsonb_extract_bool(j, '$[1]') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+---------------------------------+ -| id | j | jsonb_extract_bool(`j`, '$[1]') | -+------+---------------------------------------------------------------+---------------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | NULL | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | 1 | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | -| 26 | {"k1":"v1","k2":200} | NULL | -+------+---------------------------------------------------------------+---------------------------------+ -19 rows in set (0.01 sec) -``` - -- jsonb_extract_isnull 获取json null类型字段,null返回1,非null返回0 -- 需要注意的是json null和SQL NULL不一样,SQL NULL表示某个字段的值不存在,而json null表示值存在但是是一个特殊值null -``` -mysql> SELECT id, j, jsonb_extract_isnull(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_extract_isnull(`j`, '$') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | 1 | -| 3 | true | 0 | -| 4 | false | 0 | -| 5 | 100 | 0 | -| 6 | 10000 | 0 | -| 7 | 1000000000 | 0 | -| 8 | 1152921504606846976 | 0 | -| 9 | 6.18 | 0 | -| 10 | "abcd" | 0 | -| 11 | {} | 0 | -| 12 | {"k1":"v31","k2":300} | 0 | -| 13 | [] | 0 | -| 14 | [123,456] | 0 | -| 15 | ["abc","def"] | 0 | -| 16 | [null,true,false,100,6.18,"abc"] | 0 | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 0 | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 0 | -| 26 | {"k1":"v1","k2":200} | 0 | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.03 sec) - -``` - -#### 用jsonb_exists_path检查json内的某个字段是否存在 - -``` -mysql> SELECT id, j, jsonb_exists_path(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+-----------------------------+ -| id | j | jsonb_exists_path(`j`, '$') | -+------+---------------------------------------------------------------+-----------------------------+ -| 1 | NULL | NULL | -| 2 | null | 1 | -| 3 | true | 1 | -| 4 | false | 1 | -| 5 | 100 | 1 | -| 6 | 10000 | 1 | -| 7 | 1000000000 | 1 | -| 8 | 1152921504606846976 | 1 | -| 9 | 6.18 | 1 | -| 10 | "abcd" | 1 | -| 11 | {} | 1 | -| 12 | {"k1":"v31","k2":300} | 1 | -| 13 | [] | 1 | -| 14 | [123,456] | 1 | -| 15 | ["abc","def"] | 1 | -| 16 | [null,true,false,100,6.18,"abc"] | 1 | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 1 | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 1 | -| 26 | {"k1":"v1","k2":200} | 1 | -+------+---------------------------------------------------------------+-----------------------------+ -19 rows in set (0.02 sec) - -mysql> SELECT id, j, jsonb_exists_path(j, '$.k1') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_exists_path(`j`, '$.k1') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | 0 | -| 3 | true | 0 | -| 4 | false | 0 | -| 5 | 100 | 0 | -| 6 | 10000 | 0 | -| 7 | 1000000000 | 0 | -| 8 | 1152921504606846976 | 0 | -| 9 | 6.18 | 0 | -| 10 | "abcd" | 0 | -| 11 | {} | 0 | -| 12 | {"k1":"v31","k2":300} | 1 | -| 13 | [] | 0 | -| 14 | [123,456] | 0 | -| 15 | ["abc","def"] | 0 | -| 16 | [null,true,false,100,6.18,"abc"] | 0 | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 0 | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 1 | -| 26 | {"k1":"v1","k2":200} | 1 | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.03 sec) - -mysql> SELECT id, j, jsonb_exists_path(j, '$[2]') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+--------------------------------+ -| id | j | jsonb_exists_path(`j`, '$[2]') | -+------+---------------------------------------------------------------+--------------------------------+ -| 1 | NULL | NULL | -| 2 | null | 0 | -| 3 | true | 0 | -| 4 | false | 0 | -| 5 | 100 | 0 | -| 6 | 10000 | 0 | -| 7 | 1000000000 | 0 | -| 8 | 1152921504606846976 | 0 | -| 9 | 6.18 | 0 | -| 10 | "abcd" | 0 | -| 11 | {} | 0 | -| 12 | {"k1":"v31","k2":300} | 0 | -| 13 | [] | 0 | -| 14 | [123,456] | 0 | -| 15 | ["abc","def"] | 0 | -| 16 | [null,true,false,100,6.18,"abc"] | 1 | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 1 | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 0 | -| 26 | {"k1":"v1","k2":200} | 0 | -+------+---------------------------------------------------------------+--------------------------------+ -19 rows in set (0.02 sec) - - -``` - -#### 用jsonb_type获取json内的某个字段的类型 - -- 返回json path对应的json字段类型,如果不存在返回NULL -``` -mysql> SELECT id, j, jsonb_type(j, '$') FROM test_jsonb ORDER BY id; -+------+---------------------------------------------------------------+----------------------+ -| id | j | jsonb_type(`j`, '$') | -+------+---------------------------------------------------------------+----------------------+ -| 1 | NULL | NULL | -| 2 | null | null | -| 3 | true | bool | -| 4 | false | bool | -| 5 | 100 | int | -| 6 | 10000 | int | -| 7 | 1000000000 | int | -| 8 | 1152921504606846976 | bigint | -| 9 | 6.18 | double | -| 10 | "abcd" | string | -| 11 | {} | object | -| 12 | {"k1":"v31","k2":300} | object | -| 13 | [] | array | -| 14 | [123,456] | array | -| 15 | ["abc","def"] | array | -| 16 | [null,true,false,100,6.18,"abc"] | array | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | array | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | object | -| 26 | {"k1":"v1","k2":200} | object | -+------+---------------------------------------------------------------+----------------------+ -19 rows in set (0.02 sec) - -mysql> select id, j, jsonb_type(j, '$.k1') from test_jsonb order by id; -+------+---------------------------------------------------------------+-------------------------+ -| id | j | jsonb_type(`j`, '$.k1') | -+------+---------------------------------------------------------------+-------------------------+ -| 1 | NULL | NULL | -| 2 | null | NULL | -| 3 | true | NULL | -| 4 | false | NULL | -| 5 | 100 | NULL | -| 6 | 10000 | NULL | -| 7 | 1000000000 | NULL | -| 8 | 1152921504606846976 | NULL | -| 9 | 6.18 | NULL | -| 10 | "abcd" | NULL | -| 11 | {} | NULL | -| 12 | {"k1":"v31","k2":300} | string | -| 13 | [] | NULL | -| 14 | [123,456] | NULL | -| 15 | ["abc","def"] | NULL | -| 16 | [null,true,false,100,6.18,"abc"] | NULL | -| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | -| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | string | -| 26 | {"k1":"v1","k2":200} | string | -+------+---------------------------------------------------------------+-------------------------+ -19 rows in set (0.03 sec) - -``` - -### keywords -JSONB, JSON, jsonb_parse, jsonb_parse_error_to_null, jsonb_parse_error_to_value, jsonb_extract, jsonb_extract_isnull, jsonb_extract_bool, jsonb_extract_int, jsonb_extract_bigint, jsonb_extract_double, jsonb_extract_string, jsonb_exists_path, jsonb_type diff --git a/docs/zh-CN/docs/sql-manual/sql-reference/Data-Types/JSONB.md b/docs/zh-CN/docs/sql-manual/sql-reference/Data-Types/JSONB.md index 80c71df733..30dfc96cd1 100644 --- a/docs/zh-CN/docs/sql-manual/sql-reference/Data-Types/JSONB.md +++ b/docs/zh-CN/docs/sql-manual/sql-reference/Data-Types/JSONB.md @@ -35,8 +35,772 @@ under the License. 2. 二进制存储格式更加高效,通过jsonb_extract等函数可以高效访问JSON内部字段,比get_json_xx函数快几倍 ### example - JSONB类型通过jsonb_parse函数从JSON字符串创建,通过jsonb_extract系列函数访问内部字段,具体使用方式参考jsonb tutorial。 + 用一个从建表、导数据、查询全周期的例子说明JSONB数据类型的功能和用法。 + +#### 创建库表 + +``` +CREATE DATABASE testdb; + +USE testdb; + +CREATE TABLE test_jsonb ( + id INT, + j JSONB +) +DUPLICATE KEY(id) +DISTRIBUTED BY HASH(id) BUCKETS 10 +PROPERTIES("replication_num" = "1"); +``` + +#### 导入数据 + +##### stream load 导入test_jsonb.csv测试数据 + +- 测试数据有2列,第一列id,第二列是json +- 测试数据有25行,其中前18行的json是合法的,后7行的json是非法的 + +``` +1 \N +2 null +3 true +4 false +5 100 +6 10000 +7 1000000000 +8 1152921504606846976 +9 6.18 +10 "abcd" +11 {} +12 {"k1":"v31", "k2": 300} +13 [] +14 [123, 456] +15 ["abc", "def"] +16 [null, true, false, 100, 6.18, "abc"] +17 [{"k1":"v41", "k2": 400}, 1, "a", 3.14] +18 {"k1":"v31", "k2": 300, "a1": [{"k1":"v41", "k2": 400}, 1, "a", 3.14]} +19 '' +20 'abc' +21 abc +22 100x +23 6.a8 +24 {x +25 [123, abc] +``` + +- 由于有28%的非法数据,默认会失败报错 "too many filtered rows" +``` +curl --location-trusted -u root: -T test_jsonb.csv http://127.0.0.1:8840/api/testdb/test_jsonb/_stream_load +{ + "TxnId": 12019, + "Label": "744d9821-9c9f-43dc-bf3b-7ab048f14e32", + "TwoPhaseCommit": "false", + "Status": "Fail", + "Message": "too many filtered rows", + "NumberTotalRows": 25, + "NumberLoadedRows": 18, + "NumberFilteredRows": 7, + "NumberUnselectedRows": 0, + "LoadBytes": 380, + "LoadTimeMs": 48, + "BeginTxnTimeMs": 0, + "StreamLoadPutTimeMs": 1, + "ReadDataTimeMs": 0, + "WriteDataTimeMs": 45, + "CommitAndPublishTimeMs": 0, + "ErrorURL": "http://172.21.0.5:8840/api/_load_error_log?file=__shard_2/error_log_insert_stmt_95435c4bf5f156df-426735082a9296af_95435c4bf5f156df_426735082a9296af" +} +``` + +- 设置容错率参数 'max_filter_ratio: 0.3' +``` +curl --location-trusted -u root: -H 'max_filter_ratio: 0.3' -T test_jsonb.csv http://127.0.0.1:8840/api/testdb/test_jsonb/_stream_load +{ + "TxnId": 12017, + "Label": "f37a50c1-43e9-4f4e-a159-a3db6abe2579", + "TwoPhaseCommit": "false", + "Status": "Success", + "Message": "OK", + "NumberTotalRows": 25, + "NumberLoadedRows": 18, + "NumberFilteredRows": 7, + "NumberUnselectedRows": 0, + "LoadBytes": 380, + "LoadTimeMs": 68, + "BeginTxnTimeMs": 0, + "StreamLoadPutTimeMs": 2, + "ReadDataTimeMs": 0, + "WriteDataTimeMs": 45, + "CommitAndPublishTimeMs": 19, + "ErrorURL": "http://172.21.0.5:8840/api/_load_error_log?file=__shard_0/error_log_insert_stmt_a1463f98a7b15caf-c79399b920f5bfa3_a1463f98a7b15caf_c79399b920f5bfa3" +} +``` + +- 查看stream load导入的数据,JSONB类型的列j会自动转成JSON string展示 + +``` +mysql> SELECT * FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+ +| id | j | ++------+---------------------------------------------------------------+ +| 1 | NULL | +| 2 | null | +| 3 | true | +| 4 | false | +| 5 | 100 | +| 6 | 10000 | +| 7 | 1000000000 | +| 8 | 1152921504606846976 | +| 9 | 6.18 | +| 10 | "abcd" | +| 11 | {} | +| 12 | {"k1":"v31","k2":300} | +| 13 | [] | +| 14 | [123,456] | +| 15 | ["abc","def"] | +| 16 | [null,true,false,100,6.18,"abc"] | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | ++------+---------------------------------------------------------------+ +18 rows in set (0.03 sec) + +``` + +##### insert into 插入数据 + +- insert 1条数据,总数据从18条增加到19条 +``` +mysql> INSERT INTO test_jsonb VALUES(26, '{"k1":"v1", "k2": 200}'); +Query OK, 1 row affected (0.09 sec) +{'label':'insert_4ece6769d1b42fd_ac9f25b3b8f3dc02', 'status':'VISIBLE', 'txnId':'12016'} + +mysql> SELECT * FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+ +| id | j | ++------+---------------------------------------------------------------+ +| 1 | NULL | +| 2 | null | +| 3 | true | +| 4 | false | +| 5 | 100 | +| 6 | 10000 | +| 7 | 1000000000 | +| 8 | 1152921504606846976 | +| 9 | 6.18 | +| 10 | "abcd" | +| 11 | {} | +| 12 | {"k1":"v31","k2":300} | +| 13 | [] | +| 14 | [123,456] | +| 15 | ["abc","def"] | +| 16 | [null,true,false,100,6.18,"abc"] | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | +| 26 | {"k1":"v1","k2":200} | ++------+---------------------------------------------------------------+ +19 rows in set (0.03 sec) + +``` + +#### 查询 + +##### 用jsonb_extract取json内的某个字段 + +1. 获取整个json,$ 在json path中代表root,即整个json +``` ++------+---------------------------------------------------------------+---------------------------------------------------------------+ +| id | j | jsonb_extract(`j`, '$') | ++------+---------------------------------------------------------------+---------------------------------------------------------------+ +| 1 | NULL | NULL | +| 2 | null | null | +| 3 | true | true | +| 4 | false | false | +| 5 | 100 | 100 | +| 6 | 10000 | 10000 | +| 7 | 1000000000 | 1000000000 | +| 8 | 1152921504606846976 | 1152921504606846976 | +| 9 | 6.18 | 6.18 | +| 10 | "abcd" | "abcd" | +| 11 | {} | {} | +| 12 | {"k1":"v31","k2":300} | {"k1":"v31","k2":300} | +| 13 | [] | [] | +| 14 | [123,456] | [123,456] | +| 15 | ["abc","def"] | ["abc","def"] | +| 16 | [null,true,false,100,6.18,"abc"] | [null,true,false,100,6.18,"abc"] | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | [{"k1":"v41","k2":400},1,"a",3.14] | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | +| 26 | {"k1":"v1","k2":200} | {"k1":"v1","k2":200} | ++------+---------------------------------------------------------------+---------------------------------------------------------------+ +19 rows in set (0.03 sec) +``` + +1. 获取k1字段,没有k1字段的行返回NULL +``` +mysql> SELECT id, j, jsonb_extract(j, '$.k1') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+----------------------------+ +| id | j | jsonb_extract(`j`, '$.k1') | ++------+---------------------------------------------------------------+----------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | "v31" | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | "v31" | +| 26 | {"k1":"v1","k2":200} | "v1" | ++------+---------------------------------------------------------------+----------------------------+ +19 rows in set (0.03 sec) +``` + +1. 获取顶层数组的第0个元素 +``` +mysql> SELECT id, j, jsonb_extract(j, '$[0]') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+----------------------------+ +| id | j | jsonb_extract(`j`, '$[0]') | ++------+---------------------------------------------------------------+----------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | 123 | +| 15 | ["abc","def"] | "abc" | +| 16 | [null,true,false,100,6.18,"abc"] | null | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | {"k1":"v41","k2":400} | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+----------------------------+ +19 rows in set (0.03 sec) +``` + +1. 获取整个json array +``` +mysql> SELECT id, j, jsonb_extract(j, '$.a1') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+------------------------------------+ +| id | j | jsonb_extract(`j`, '$.a1') | ++------+---------------------------------------------------------------+------------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | [{"k1":"v41","k2":400},1,"a",3.14] | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+------------------------------------+ +19 rows in set (0.02 sec) +``` + +1. 获取json array中嵌套object的字段 +``` +mysql> SELECT id, j, jsonb_extract(j, '$.a1[0]'), jsonb_extract(j, '$.a1[0].k1') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+-------------------------------+----------------------------------+ +| id | j | jsonb_extract(`j`, '$.a1[0]') | jsonb_extract(`j`, '$.a1[0].k1') | ++------+---------------------------------------------------------------+-------------------------------+----------------------------------+ +| 1 | NULL | NULL | NULL | +| 2 | null | NULL | NULL | +| 3 | true | NULL | NULL | +| 4 | false | NULL | NULL | +| 5 | 100 | NULL | NULL | +| 6 | 10000 | NULL | NULL | +| 7 | 1000000000 | NULL | NULL | +| 8 | 1152921504606846976 | NULL | NULL | +| 9 | 6.18 | NULL | NULL | +| 10 | "abcd" | NULL | NULL | +| 11 | {} | NULL | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | NULL | +| 13 | [] | NULL | NULL | +| 14 | [123,456] | NULL | NULL | +| 15 | ["abc","def"] | NULL | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | {"k1":"v41","k2":400} | "v41" | +| 26 | {"k1":"v1","k2":200} | NULL | NULL | ++------+---------------------------------------------------------------+-------------------------------+----------------------------------+ +19 rows in set (0.02 sec) + +``` + +1. 获取具体类型的 +- jsonb_extract_string 获取string类型字段,非string类型转成string +``` +mysql> SELECT id, j, jsonb_extract_string(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+---------------------------------------------------------------+ +| id | j | jsonb_extract_string(`j`, '$') | ++------+---------------------------------------------------------------+---------------------------------------------------------------+ +| 1 | NULL | NULL | +| 2 | null | null | +| 3 | true | true | +| 4 | false | false | +| 5 | 100 | 100 | +| 6 | 10000 | 10000 | +| 7 | 1000000000 | 1000000000 | +| 8 | 1152921504606846976 | 1152921504606846976 | +| 9 | 6.18 | 6.18 | +| 10 | "abcd" | abcd | +| 11 | {} | {} | +| 12 | {"k1":"v31","k2":300} | {"k1":"v31","k2":300} | +| 13 | [] | [] | +| 14 | [123,456] | [123,456] | +| 15 | ["abc","def"] | ["abc","def"] | +| 16 | [null,true,false,100,6.18,"abc"] | [null,true,false,100,6.18,"abc"] | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | [{"k1":"v41","k2":400},1,"a",3.14] | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | +| 26 | {"k1":"v1","k2":200} | {"k1":"v1","k2":200} | ++------+---------------------------------------------------------------+---------------------------------------------------------------+ +19 rows in set (0.02 sec) + +mysql> SELECT id, j, jsonb_extract_string(j, '$.k1') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+-----------------------------------+ +| id | j | jsonb_extract_string(`j`, '$.k1') | ++------+---------------------------------------------------------------+-----------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | v31 | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | v31 | +| 26 | {"k1":"v1","k2":200} | v1 | ++------+---------------------------------------------------------------+-----------------------------------+ +19 rows in set (0.03 sec) + +``` + +- jsonb_extract_int 获取int类型字段,非int类型返回NULL +``` +mysql> SELECT id, j, jsonb_extract_int(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+-----------------------------+ +| id | j | jsonb_extract_int(`j`, '$') | ++------+---------------------------------------------------------------+-----------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | 100 | +| 6 | 10000 | 10000 | +| 7 | 1000000000 | 1000000000 | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+-----------------------------+ +19 rows in set (0.02 sec) + +mysql> SELECT id, j, jsonb_extract_int(j, '$.k2') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+--------------------------------+ +| id | j | jsonb_extract_int(`j`, '$.k2') | ++------+---------------------------------------------------------------+--------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | 300 | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 | +| 26 | {"k1":"v1","k2":200} | 200 | ++------+---------------------------------------------------------------+--------------------------------+ +19 rows in set (0.03 sec) +``` + +- jsonb_extract_bigint 获取bigint类型字段,非bigint类型返回NULL +``` +mysql> SELECT id, j, jsonb_extract_bigint(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+--------------------------------+ +| id | j | jsonb_extract_bigint(`j`, '$') | ++------+---------------------------------------------------------------+--------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | 100 | +| 6 | 10000 | 10000 | +| 7 | 1000000000 | 1000000000 | +| 8 | 1152921504606846976 | 1152921504606846976 | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+--------------------------------+ +19 rows in set (0.03 sec) + +mysql> SELECT id, j, jsonb_extract_bigint(j, '$.k2') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+-----------------------------------+ +| id | j | jsonb_extract_bigint(`j`, '$.k2') | ++------+---------------------------------------------------------------+-----------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | 300 | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 | +| 26 | {"k1":"v1","k2":200} | 200 | ++------+---------------------------------------------------------------+-----------------------------------+ +19 rows in set (0.02 sec) + +``` + +- jsonb_extract_double 获取double类型字段,非double类型返回NULL +``` +mysql> SELECT id, j, jsonb_extract_double(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+--------------------------------+ +| id | j | jsonb_extract_double(`j`, '$') | ++------+---------------------------------------------------------------+--------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | 100 | +| 6 | 10000 | 10000 | +| 7 | 1000000000 | 1000000000 | +| 8 | 1152921504606846976 | 1.152921504606847e+18 | +| 9 | 6.18 | 6.18 | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+--------------------------------+ +19 rows in set (0.02 sec) + +mysql> SELECT id, j, jsonb_extract_double(j, '$.k2') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+-----------------------------------+ +| id | j | jsonb_extract_double(`j`, '$.k2') | ++------+---------------------------------------------------------------+-----------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | 300 | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 | +| 26 | {"k1":"v1","k2":200} | 200 | ++------+---------------------------------------------------------------+-----------------------------------+ +19 rows in set (0.03 sec) +``` + +- jsonb_extract_bool 获取bool类型字段,非bool类型返回NULL +``` +mysql> SELECT id, j, jsonb_extract_bool(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+------------------------------+ +| id | j | jsonb_extract_bool(`j`, '$') | ++------+---------------------------------------------------------------+------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | 1 | +| 4 | false | 0 | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+------------------------------+ +19 rows in set (0.01 sec) + +mysql> SELECT id, j, jsonb_extract_bool(j, '$[1]') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+---------------------------------+ +| id | j | jsonb_extract_bool(`j`, '$[1]') | ++------+---------------------------------------------------------------+---------------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | NULL | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | 1 | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL | +| 26 | {"k1":"v1","k2":200} | NULL | ++------+---------------------------------------------------------------+---------------------------------+ +19 rows in set (0.01 sec) +``` + +- jsonb_extract_isnull 获取json null类型字段,null返回1,非null返回0 +- 需要注意的是json null和SQL NULL不一样,SQL NULL表示某个字段的值不存在,而json null表示值存在但是是一个特殊值null +``` +mysql> SELECT id, j, jsonb_extract_isnull(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+--------------------------------+ +| id | j | jsonb_extract_isnull(`j`, '$') | ++------+---------------------------------------------------------------+--------------------------------+ +| 1 | NULL | NULL | +| 2 | null | 1 | +| 3 | true | 0 | +| 4 | false | 0 | +| 5 | 100 | 0 | +| 6 | 10000 | 0 | +| 7 | 1000000000 | 0 | +| 8 | 1152921504606846976 | 0 | +| 9 | 6.18 | 0 | +| 10 | "abcd" | 0 | +| 11 | {} | 0 | +| 12 | {"k1":"v31","k2":300} | 0 | +| 13 | [] | 0 | +| 14 | [123,456] | 0 | +| 15 | ["abc","def"] | 0 | +| 16 | [null,true,false,100,6.18,"abc"] | 0 | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 0 | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 0 | +| 26 | {"k1":"v1","k2":200} | 0 | ++------+---------------------------------------------------------------+--------------------------------+ +19 rows in set (0.03 sec) + +``` + +##### 用jsonb_exists_path检查json内的某个字段是否存在 + +``` +mysql> SELECT id, j, jsonb_exists_path(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+-----------------------------+ +| id | j | jsonb_exists_path(`j`, '$') | ++------+---------------------------------------------------------------+-----------------------------+ +| 1 | NULL | NULL | +| 2 | null | 1 | +| 3 | true | 1 | +| 4 | false | 1 | +| 5 | 100 | 1 | +| 6 | 10000 | 1 | +| 7 | 1000000000 | 1 | +| 8 | 1152921504606846976 | 1 | +| 9 | 6.18 | 1 | +| 10 | "abcd" | 1 | +| 11 | {} | 1 | +| 12 | {"k1":"v31","k2":300} | 1 | +| 13 | [] | 1 | +| 14 | [123,456] | 1 | +| 15 | ["abc","def"] | 1 | +| 16 | [null,true,false,100,6.18,"abc"] | 1 | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 1 | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 1 | +| 26 | {"k1":"v1","k2":200} | 1 | ++------+---------------------------------------------------------------+-----------------------------+ +19 rows in set (0.02 sec) + +mysql> SELECT id, j, jsonb_exists_path(j, '$.k1') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+--------------------------------+ +| id | j | jsonb_exists_path(`j`, '$.k1') | ++------+---------------------------------------------------------------+--------------------------------+ +| 1 | NULL | NULL | +| 2 | null | 0 | +| 3 | true | 0 | +| 4 | false | 0 | +| 5 | 100 | 0 | +| 6 | 10000 | 0 | +| 7 | 1000000000 | 0 | +| 8 | 1152921504606846976 | 0 | +| 9 | 6.18 | 0 | +| 10 | "abcd" | 0 | +| 11 | {} | 0 | +| 12 | {"k1":"v31","k2":300} | 1 | +| 13 | [] | 0 | +| 14 | [123,456] | 0 | +| 15 | ["abc","def"] | 0 | +| 16 | [null,true,false,100,6.18,"abc"] | 0 | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 0 | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 1 | +| 26 | {"k1":"v1","k2":200} | 1 | ++------+---------------------------------------------------------------+--------------------------------+ +19 rows in set (0.03 sec) + +mysql> SELECT id, j, jsonb_exists_path(j, '$[2]') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+--------------------------------+ +| id | j | jsonb_exists_path(`j`, '$[2]') | ++------+---------------------------------------------------------------+--------------------------------+ +| 1 | NULL | NULL | +| 2 | null | 0 | +| 3 | true | 0 | +| 4 | false | 0 | +| 5 | 100 | 0 | +| 6 | 10000 | 0 | +| 7 | 1000000000 | 0 | +| 8 | 1152921504606846976 | 0 | +| 9 | 6.18 | 0 | +| 10 | "abcd" | 0 | +| 11 | {} | 0 | +| 12 | {"k1":"v31","k2":300} | 0 | +| 13 | [] | 0 | +| 14 | [123,456] | 0 | +| 15 | ["abc","def"] | 0 | +| 16 | [null,true,false,100,6.18,"abc"] | 1 | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 1 | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 0 | +| 26 | {"k1":"v1","k2":200} | 0 | ++------+---------------------------------------------------------------+--------------------------------+ +19 rows in set (0.02 sec) + + +``` + +##### 用jsonb_type获取json内的某个字段的类型 + +- 返回json path对应的json字段类型,如果不存在返回NULL +``` +mysql> SELECT id, j, jsonb_type(j, '$') FROM test_jsonb ORDER BY id; ++------+---------------------------------------------------------------+----------------------+ +| id | j | jsonb_type(`j`, '$') | ++------+---------------------------------------------------------------+----------------------+ +| 1 | NULL | NULL | +| 2 | null | null | +| 3 | true | bool | +| 4 | false | bool | +| 5 | 100 | int | +| 6 | 10000 | int | +| 7 | 1000000000 | int | +| 8 | 1152921504606846976 | bigint | +| 9 | 6.18 | double | +| 10 | "abcd" | string | +| 11 | {} | object | +| 12 | {"k1":"v31","k2":300} | object | +| 13 | [] | array | +| 14 | [123,456] | array | +| 15 | ["abc","def"] | array | +| 16 | [null,true,false,100,6.18,"abc"] | array | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | array | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | object | +| 26 | {"k1":"v1","k2":200} | object | ++------+---------------------------------------------------------------+----------------------+ +19 rows in set (0.02 sec) + +mysql> select id, j, jsonb_type(j, '$.k1') from test_jsonb order by id; ++------+---------------------------------------------------------------+-------------------------+ +| id | j | jsonb_type(`j`, '$.k1') | ++------+---------------------------------------------------------------+-------------------------+ +| 1 | NULL | NULL | +| 2 | null | NULL | +| 3 | true | NULL | +| 4 | false | NULL | +| 5 | 100 | NULL | +| 6 | 10000 | NULL | +| 7 | 1000000000 | NULL | +| 8 | 1152921504606846976 | NULL | +| 9 | 6.18 | NULL | +| 10 | "abcd" | NULL | +| 11 | {} | NULL | +| 12 | {"k1":"v31","k2":300} | string | +| 13 | [] | NULL | +| 14 | [123,456] | NULL | +| 15 | ["abc","def"] | NULL | +| 16 | [null,true,false,100,6.18,"abc"] | NULL | +| 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | +| 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | string | +| 26 | {"k1":"v1","k2":200} | string | ++------+---------------------------------------------------------------+-------------------------+ +19 rows in set (0.03 sec) + +``` ### keywords - - JSONB JSON +JSONB, JSON, jsonb_parse, jsonb_parse_error_to_null, jsonb_parse_error_to_value, jsonb_extract, jsonb_extract_isnull, jsonb_extract_bool, jsonb_extract_int, jsonb_extract_bigint, jsonb_extract_double, jsonb_extract_string, jsonb_exists_path, jsonb_type diff --git a/regression-test/data/jsonb_p0/test_jsonb_load_and_function.out b/regression-test/data/jsonb_p0/test_jsonb_load_and_function.out index e50035ec83..b2b68133f6 100644 --- a/regression-test/data/jsonb_p0/test_jsonb_load_and_function.out +++ b/regression-test/data/jsonb_p0/test_jsonb_load_and_function.out @@ -420,24 +420,24 @@ -- !select -- 1 \N \N -2 null \N -3 true \N -4 false \N -5 100 \N -6 10000 \N -7 1000000000 \N -8 1152921504606846976 \N -9 6.18 \N +2 null null +3 true true +4 false false +5 100 100 +6 10000 10000 +7 1000000000 1000000000 +8 1152921504606846976 1152921504606846976 +9 6.18 6.18 10 "abcd" abcd -11 {} \N -12 {"k1":"v31","k2":300} \N -13 [] \N -14 [123,456] \N -15 ["abc","def"] \N -16 [null,true,false,100,6.18,"abc"] \N -17 [{"k1":"v41","k2":400},1,"a",3.14] \N -18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} \N -26 {"k1":"v1","k2":200} \N +11 {} {} +12 {"k1":"v31","k2":300} {"k1":"v31","k2":300} +13 [] [] +14 [123,456] [123,456] +15 ["abc","def"] ["abc","def"] +16 [null,true,false,100,6.18,"abc"] [null,true,false,100,6.18,"abc"] +17 [{"k1":"v41","k2":400},1,"a",3.14] [{"k1":"v41","k2":400},1,"a",3.14] +18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} +26 {"k1":"v1","k2":200} {"k1":"v1","k2":200} -- !select -- 1 \N \N @@ -472,14 +472,14 @@ 9 6.18 \N 10 "abcd" \N 11 {} \N -12 {"k1":"v31","k2":300} \N +12 {"k1":"v31","k2":300} 300 13 [] \N 14 [123,456] \N 15 ["abc","def"] \N 16 [null,true,false,100,6.18,"abc"] \N 17 [{"k1":"v41","k2":400},1,"a",3.14] \N -18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} \N -26 {"k1":"v1","k2":200} \N +18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} 300 +26 {"k1":"v1","k2":200} 200 -- !select -- 1 \N \N @@ -495,10 +495,10 @@ 11 {} \N 12 {"k1":"v31","k2":300} \N 13 [] \N -14 [123,456] \N +14 [123,456] 123 15 ["abc","def"] abc -16 [null,true,false,100,6.18,"abc"] \N -17 [{"k1":"v41","k2":400},1,"a",3.14] \N +16 [null,true,false,100,6.18,"abc"] null +17 [{"k1":"v41","k2":400},1,"a",3.14] {"k1":"v41","k2":400} 18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} \N 26 {"k1":"v1","k2":200} \N @@ -516,10 +516,10 @@ 11 {} \N 12 {"k1":"v31","k2":300} \N 13 [] \N -14 [123,456] \N +14 [123,456] 456 15 ["abc","def"] def -16 [null,true,false,100,6.18,"abc"] \N -17 [{"k1":"v41","k2":400},1,"a",3.14] \N +16 [null,true,false,100,6.18,"abc"] true +17 [{"k1":"v41","k2":400},1,"a",3.14] 1 18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} \N 26 {"k1":"v1","k2":200} \N @@ -539,7 +539,7 @@ 13 [] \N 14 [123,456] \N 15 ["abc","def"] \N -16 [null,true,false,100,6.18,"abc"] \N +16 [null,true,false,100,6.18,"abc"] false 17 [{"k1":"v41","k2":400},1,"a",3.14] a 18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} \N 26 {"k1":"v1","k2":200} \N @@ -560,8 +560,8 @@ 13 [] \N 14 [123,456] \N 15 ["abc","def"] \N -16 [null,true,false,100,6.18,"abc"] \N -17 [{"k1":"v41","k2":400},1,"a",3.14] \N +16 [null,true,false,100,6.18,"abc"] 100 +17 [{"k1":"v41","k2":400},1,"a",3.14] 3.14 18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} \N 26 {"k1":"v1","k2":200} \N @@ -581,7 +581,7 @@ 13 [] \N 14 [123,456] \N 15 ["abc","def"] \N -16 [null,true,false,100,6.18,"abc"] \N +16 [null,true,false,100,6.18,"abc"] 6.18 17 [{"k1":"v41","k2":400},1,"a",3.14] \N 18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} \N 26 {"k1":"v1","k2":200} \N @@ -667,7 +667,7 @@ 15 ["abc","def"] \N 16 [null,true,false,100,6.18,"abc"] \N 17 [{"k1":"v41","k2":400},1,"a",3.14] \N -18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} \N +18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} [{"k1":"v41","k2":400},1,"a",3.14] 26 {"k1":"v1","k2":200} \N -- !select -- @@ -688,7 +688,7 @@ 15 ["abc","def"] \N 16 [null,true,false,100,6.18,"abc"] \N 17 [{"k1":"v41","k2":400},1,"a",3.14] \N -18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} \N +18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} {"k1":"v41","k2":400} 26 {"k1":"v1","k2":200} \N -- !select -- @@ -709,7 +709,7 @@ 15 ["abc","def"] \N 16 [null,true,false,100,6.18,"abc"] \N 17 [{"k1":"v41","k2":400},1,"a",3.14] \N -18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} \N +18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} 1 26 {"k1":"v1","k2":200} \N -- !select -- @@ -751,7 +751,7 @@ 15 ["abc","def"] \N 16 [null,true,false,100,6.18,"abc"] \N 17 [{"k1":"v41","k2":400},1,"a",3.14] \N -18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} \N +18 {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} 3.14 26 {"k1":"v1","k2":200} \N -- !select --