1. 1. 数据写入时进行JSON格式校验
    2. 2. 二进制存储格式更加高效,通过jsonb_extract等函数可以高效访问JSON内部字段,比get_json_xx函数快几倍
    1. 用一个从建表、导数据、查询全周期的例子说明JSONB数据类型的功能和用法。

    创建库表

    1. CREATE DATABASE testdb;
    2. USE testdb;
    3. CREATE TABLE test_jsonb (
    4. id INT,
    5. j JSONB
    6. )
    7. DUPLICATE KEY(id)
    8. DISTRIBUTED BY HASH(id) BUCKETS 10
    9. PROPERTIES("replication_num" = "1");

    导入数据

    stream load 导入test_jsonb.csv测试数据
    • 测试数据有2列,第一列id,第二列是json
    • 测试数据有25行,其中前18行的json是合法的,后7行的json是非法的
    1. 1 \N
    2. 2 null
    3. 3 true
    4. 4 false
    5. 5 100
    6. 6 10000
    7. 7 1000000000
    8. 8 1152921504606846976
    9. 9 6.18
    10. 10 "abcd"
    11. 11 {}
    12. 12 {"k1":"v31", "k2": 300}
    13. 13 []
    14. 14 [123, 456]
    15. 15 ["abc", "def"]
    16. 16 [null, true, false, 100, 6.18, "abc"]
    17. 17 [{"k1":"v41", "k2": 400}, 1, "a", 3.14]
    18. 18 {"k1":"v31", "k2": 300, "a1": [{"k1":"v41", "k2": 400}, 1, "a", 3.14]}
    19. 19 ''
    20. 20 'abc'
    21. 21 abc
    22. 22 100x
    23. 23 6.a8
    24. 24 {x
    25. 25 [123, abc]
    • 由于有28%的非法数据,默认会失败报错 “too many filtered rows”
    1. curl --location-trusted -u root: -T test_jsonb.csv http://127.0.0.1:8840/api/testdb/test_jsonb/_stream_load
    2. {
    3. "TxnId": 12019,
    4. "Label": "744d9821-9c9f-43dc-bf3b-7ab048f14e32",
    5. "TwoPhaseCommit": "false",
    6. "Status": "Fail",
    7. "Message": "too many filtered rows",
    8. "NumberTotalRows": 25,
    9. "NumberLoadedRows": 18,
    10. "NumberFilteredRows": 7,
    11. "NumberUnselectedRows": 0,
    12. "LoadBytes": 380,
    13. "LoadTimeMs": 48,
    14. "BeginTxnTimeMs": 0,
    15. "StreamLoadPutTimeMs": 1,
    16. "ReadDataTimeMs": 0,
    17. "WriteDataTimeMs": 45,
    18. "CommitAndPublishTimeMs": 0,
    19. "ErrorURL": "http://172.21.0.5:8840/api/_load_error_log?file=__shard_2/error_log_insert_stmt_95435c4bf5f156df-426735082a9296af_95435c4bf5f156df_426735082a9296af"
    20. }
    • 设置容错率参数 ‘max_filter_ratio: 0.3’
    1. 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
    2. {
    3. "TxnId": 12017,
    4. "Label": "f37a50c1-43e9-4f4e-a159-a3db6abe2579",
    5. "TwoPhaseCommit": "false",
    6. "Status": "Success",
    7. "Message": "OK",
    8. "NumberTotalRows": 25,
    9. "NumberLoadedRows": 18,
    10. "NumberFilteredRows": 7,
    11. "NumberUnselectedRows": 0,
    12. "LoadBytes": 380,
    13. "LoadTimeMs": 68,
    14. "BeginTxnTimeMs": 0,
    15. "StreamLoadPutTimeMs": 2,
    16. "ReadDataTimeMs": 0,
    17. "WriteDataTimeMs": 45,
    18. "CommitAndPublishTimeMs": 19,
    19. "ErrorURL": "http://172.21.0.5:8840/api/_load_error_log?file=__shard_0/error_log_insert_stmt_a1463f98a7b15caf-c79399b920f5bfa3_a1463f98a7b15caf_c79399b920f5bfa3"
    20. }
    • 查看stream load导入的数据,JSONB类型的列j会自动转成JSON string展示
    insert into 插入数据
    • insert 1条数据,总数据从18条增加到19条
    1. mysql> INSERT INTO test_jsonb VALUES(26, '{"k1":"v1", "k2": 200}');
    2. Query OK, 1 row affected (0.09 sec)
    3. {'label':'insert_4ece6769d1b42fd_ac9f25b3b8f3dc02', 'status':'VISIBLE', 'txnId':'12016'}
    4. mysql> SELECT * FROM test_jsonb ORDER BY id;
    5. +------+---------------------------------------------------------------+
    6. | id | j |
    7. +------+---------------------------------------------------------------+
    8. | 1 | NULL |
    9. | 2 | null |
    10. | 3 | true |
    11. | 4 | false |
    12. | 5 | 100 |
    13. | 6 | 10000 |
    14. | 7 | 1000000000 |
    15. | 8 | 1152921504606846976 |
    16. | 9 | 6.18 |
    17. | 10 | "abcd" |
    18. | 11 | {} |
    19. | 12 | {"k1":"v31","k2":300} |
    20. | 13 | [] |
    21. | 14 | [123,456] |
    22. | 15 | ["abc","def"] |
    23. | 16 | [null,true,false,100,6.18,"abc"] |
    24. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] |
    25. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} |
    26. | 26 | {"k1":"v1","k2":200} |
    27. +------+---------------------------------------------------------------+
    28. 19 rows in set (0.03 sec)

    查询

    用jsonb_extract取json内的某个字段
    1. 获取整个json,$ 在json path中代表root,即整个json
    1. +------+---------------------------------------------------------------+---------------------------------------------------------------+
    2. | id | j | jsonb_extract(`j`, '$') |
    3. +------+---------------------------------------------------------------+---------------------------------------------------------------+
    4. | 1 | NULL | NULL |
    5. | 2 | null | null |
    6. | 3 | true | true |
    7. | 4 | false | false |
    8. | 5 | 100 | 100 |
    9. | 6 | 10000 | 10000 |
    10. | 7 | 1000000000 | 1000000000 |
    11. | 8 | 1152921504606846976 | 1152921504606846976 |
    12. | 9 | 6.18 | 6.18 |
    13. | 10 | "abcd" | "abcd" |
    14. | 11 | {} | {} |
    15. | 12 | {"k1":"v31","k2":300} | {"k1":"v31","k2":300} |
    16. | 13 | [] | [] |
    17. | 14 | [123,456] | [123,456] |
    18. | 15 | ["abc","def"] | ["abc","def"] |
    19. | 16 | [null,true,false,100,6.18,"abc"] | [null,true,false,100,6.18,"abc"] |
    20. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | [{"k1":"v41","k2":400},1,"a",3.14] |
    21. | 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]} |
    22. | 26 | {"k1":"v1","k2":200} | {"k1":"v1","k2":200} |
    23. +------+---------------------------------------------------------------+---------------------------------------------------------------+
    24. 19 rows in set (0.03 sec)
    1. 获取k1字段,没有k1字段的行返回NULL
    1. mysql> SELECT id, j, jsonb_extract(j, '$.k1') FROM test_jsonb ORDER BY id;
    2. +------+---------------------------------------------------------------+----------------------------+
    3. | id | j | jsonb_extract(`j`, '$.k1') |
    4. +------+---------------------------------------------------------------+----------------------------+
    5. | 1 | NULL | NULL |
    6. | 2 | null | NULL |
    7. | 3 | true | NULL |
    8. | 4 | false | NULL |
    9. | 5 | 100 | NULL |
    10. | 6 | 10000 | NULL |
    11. | 7 | 1000000000 | NULL |
    12. | 8 | 1152921504606846976 | NULL |
    13. | 9 | 6.18 | NULL |
    14. | 10 | "abcd" | NULL |
    15. | 11 | {} | NULL |
    16. | 12 | {"k1":"v31","k2":300} | "v31" |
    17. | 13 | [] | NULL |
    18. | 14 | [123,456] | NULL |
    19. | 15 | ["abc","def"] | NULL |
    20. | 16 | [null,true,false,100,6.18,"abc"] | NULL |
    21. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL |
    22. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | "v31" |
    23. | 26 | {"k1":"v1","k2":200} | "v1" |
    24. +------+---------------------------------------------------------------+----------------------------+
    25. 19 rows in set (0.03 sec)
    1. 获取顶层数组的第0个元素
    1. mysql> SELECT id, j, jsonb_extract(j, '$[0]') FROM test_jsonb ORDER BY id;
    2. +------+---------------------------------------------------------------+----------------------------+
    3. | id | j | jsonb_extract(`j`, '$[0]') |
    4. +------+---------------------------------------------------------------+----------------------------+
    5. | 1 | NULL | NULL |
    6. | 2 | null | NULL |
    7. | 3 | true | NULL |
    8. | 4 | false | NULL |
    9. | 5 | 100 | NULL |
    10. | 6 | 10000 | NULL |
    11. | 8 | 1152921504606846976 | NULL |
    12. | 9 | 6.18 | NULL |
    13. | 10 | "abcd" | NULL |
    14. | 11 | {} | NULL |
    15. | 12 | {"k1":"v31","k2":300} | NULL |
    16. | 13 | [] | NULL |
    17. | 14 | [123,456] | 123 |
    18. | 15 | ["abc","def"] | "abc" |
    19. | 16 | [null,true,false,100,6.18,"abc"] | null |
    20. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | {"k1":"v41","k2":400} |
    21. | 26 | {"k1":"v1","k2":200} | NULL |
    22. +------+---------------------------------------------------------------+----------------------------+
    23. 19 rows in set (0.03 sec)
    1. 获取整个json array
    1. mysql> SELECT id, j, jsonb_extract(j, '$.a1') FROM test_jsonb ORDER BY id;
    2. +------+---------------------------------------------------------------+------------------------------------+
    3. | id | j | jsonb_extract(`j`, '$.a1') |
    4. +------+---------------------------------------------------------------+------------------------------------+
    5. | 1 | NULL | NULL |
    6. | 2 | null | NULL |
    7. | 3 | true | NULL |
    8. | 4 | false | NULL |
    9. | 5 | 100 | NULL |
    10. | 6 | 10000 | NULL |
    11. | 7 | 1000000000 | NULL |
    12. | 8 | 1152921504606846976 | NULL |
    13. | 9 | 6.18 | NULL |
    14. | 10 | "abcd" | NULL |
    15. | 11 | {} | NULL |
    16. | 12 | {"k1":"v31","k2":300} | NULL |
    17. | 13 | [] | NULL |
    18. | 14 | [123,456] | NULL |
    19. | 15 | ["abc","def"] | NULL |
    20. | 16 | [null,true,false,100,6.18,"abc"] | NULL |
    21. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL |
    22. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | [{"k1":"v41","k2":400},1,"a",3.14] |
    23. | 26 | {"k1":"v1","k2":200} | NULL |
    24. +------+---------------------------------------------------------------+------------------------------------+
    25. 19 rows in set (0.02 sec)
    1. 获取json array中嵌套object的字段
    1. mysql> SELECT id, j, jsonb_extract(j, '$.a1[0]'), jsonb_extract(j, '$.a1[0].k1') FROM test_jsonb ORDER BY id;
    2. +------+---------------------------------------------------------------+-------------------------------+----------------------------------+
    3. | id | j | jsonb_extract(`j`, '$.a1[0]') | jsonb_extract(`j`, '$.a1[0].k1') |
    4. +------+---------------------------------------------------------------+-------------------------------+----------------------------------+
    5. | 1 | NULL | NULL | NULL |
    6. | 2 | null | NULL | NULL |
    7. | 3 | true | NULL | NULL |
    8. | 4 | false | NULL | NULL |
    9. | 5 | 100 | NULL | NULL |
    10. | 6 | 10000 | NULL | NULL |
    11. | 7 | 1000000000 | NULL | NULL |
    12. | 8 | 1152921504606846976 | NULL | NULL |
    13. | 9 | 6.18 | NULL | NULL |
    14. | 10 | "abcd" | NULL | NULL |
    15. | 11 | {} | NULL | NULL |
    16. | 12 | {"k1":"v31","k2":300} | NULL | NULL |
    17. | 13 | [] | NULL | NULL |
    18. | 14 | [123,456] | NULL | NULL |
    19. | 15 | ["abc","def"] | NULL | NULL |
    20. | 16 | [null,true,false,100,6.18,"abc"] | NULL | NULL |
    21. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL | NULL |
    22. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | {"k1":"v41","k2":400} | "v41" |
    23. | 26 | {"k1":"v1","k2":200} | NULL | NULL |
    24. +------+---------------------------------------------------------------+-------------------------------+----------------------------------+
    25. 19 rows in set (0.02 sec)
    1. 获取具体类型的
    • jsonb_extract_string 获取string类型字段,非string类型转成string
    • jsonb_extract_int 获取int类型字段,非int类型返回NULL
    1. mysql> SELECT id, j, jsonb_extract_int(j, '$') FROM test_jsonb ORDER BY id;
    2. +------+---------------------------------------------------------------+-----------------------------+
    3. | id | j | jsonb_extract_int(`j`, '$') |
    4. +------+---------------------------------------------------------------+-----------------------------+
    5. | 1 | NULL | NULL |
    6. | 2 | null | NULL |
    7. | 3 | true | NULL |
    8. | 4 | false | NULL |
    9. | 5 | 100 | 100 |
    10. | 6 | 10000 | 10000 |
    11. | 7 | 1000000000 | 1000000000 |
    12. | 8 | 1152921504606846976 | NULL |
    13. | 9 | 6.18 | NULL |
    14. | 10 | "abcd" | NULL |
    15. | 11 | {} | NULL |
    16. | 12 | {"k1":"v31","k2":300} | NULL |
    17. | 13 | [] | NULL |
    18. | 14 | [123,456] | NULL |
    19. | 15 | ["abc","def"] | NULL |
    20. | 16 | [null,true,false,100,6.18,"abc"] | NULL |
    21. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL |
    22. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL |
    23. | 26 | {"k1":"v1","k2":200} | NULL |
    24. +------+---------------------------------------------------------------+-----------------------------+
    25. 19 rows in set (0.02 sec)
    26. mysql> SELECT id, j, jsonb_extract_int(j, '$.k2') FROM test_jsonb ORDER BY id;
    27. +------+---------------------------------------------------------------+--------------------------------+
    28. | id | j | jsonb_extract_int(`j`, '$.k2') |
    29. +------+---------------------------------------------------------------+--------------------------------+
    30. | 1 | NULL | NULL |
    31. | 2 | null | NULL |
    32. | 3 | true | NULL |
    33. | 4 | false | NULL |
    34. | 5 | 100 | NULL |
    35. | 6 | 10000 | NULL |
    36. | 7 | 1000000000 | NULL |
    37. | 8 | 1152921504606846976 | NULL |
    38. | 9 | 6.18 | NULL |
    39. | 10 | "abcd" | NULL |
    40. | 11 | {} | NULL |
    41. | 12 | {"k1":"v31","k2":300} | 300 |
    42. | 13 | [] | NULL |
    43. | 14 | [123,456] | NULL |
    44. | 15 | ["abc","def"] | NULL |
    45. | 16 | [null,true,false,100,6.18,"abc"] | NULL |
    46. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL |
    47. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 |
    48. | 26 | {"k1":"v1","k2":200} | 200 |
    49. +------+---------------------------------------------------------------+--------------------------------+
    50. 19 rows in set (0.03 sec)
    • jsonb_extract_bigint 获取bigint类型字段,非bigint类型返回NULL
    1. mysql> SELECT id, j, jsonb_extract_bigint(j, '$') FROM test_jsonb ORDER BY id;
    2. +------+---------------------------------------------------------------+--------------------------------+
    3. | id | j | jsonb_extract_bigint(`j`, '$') |
    4. +------+---------------------------------------------------------------+--------------------------------+
    5. | 1 | NULL | NULL |
    6. | 2 | null | NULL |
    7. | 3 | true | NULL |
    8. | 4 | false | NULL |
    9. | 5 | 100 | 100 |
    10. | 6 | 10000 | 10000 |
    11. | 7 | 1000000000 | 1000000000 |
    12. | 8 | 1152921504606846976 | 1152921504606846976 |
    13. | 9 | 6.18 | NULL |
    14. | 10 | "abcd" | NULL |
    15. | 11 | {} | NULL |
    16. | 12 | {"k1":"v31","k2":300} | NULL |
    17. | 13 | [] | NULL |
    18. | 14 | [123,456] | NULL |
    19. | 15 | ["abc","def"] | NULL |
    20. | 16 | [null,true,false,100,6.18,"abc"] | NULL |
    21. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL |
    22. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL |
    23. | 26 | {"k1":"v1","k2":200} | NULL |
    24. +------+---------------------------------------------------------------+--------------------------------+
    25. 19 rows in set (0.03 sec)
    26. mysql> SELECT id, j, jsonb_extract_bigint(j, '$.k2') FROM test_jsonb ORDER BY id;
    27. +------+---------------------------------------------------------------+-----------------------------------+
    28. | id | j | jsonb_extract_bigint(`j`, '$.k2') |
    29. +------+---------------------------------------------------------------+-----------------------------------+
    30. | 1 | NULL | NULL |
    31. | 2 | null | NULL |
    32. | 3 | true | NULL |
    33. | 4 | false | NULL |
    34. | 5 | 100 | NULL |
    35. | 6 | 10000 | NULL |
    36. | 7 | 1000000000 | NULL |
    37. | 8 | 1152921504606846976 | NULL |
    38. | 9 | 6.18 | NULL |
    39. | 10 | "abcd" | NULL |
    40. | 11 | {} | NULL |
    41. | 12 | {"k1":"v31","k2":300} | 300 |
    42. | 13 | [] | NULL |
    43. | 14 | [123,456] | NULL |
    44. | 15 | ["abc","def"] | NULL |
    45. | 16 | [null,true,false,100,6.18,"abc"] | NULL |
    46. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL |
    47. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 |
    48. | 26 | {"k1":"v1","k2":200} | 200 |
    49. +------+---------------------------------------------------------------+-----------------------------------+
    50. 19 rows in set (0.02 sec)
    • jsonb_extract_double 获取double类型字段,非double类型返回NULL
    1. mysql> SELECT id, j, jsonb_extract_double(j, '$') FROM test_jsonb ORDER BY id;
    2. +------+---------------------------------------------------------------+--------------------------------+
    3. | id | j | jsonb_extract_double(`j`, '$') |
    4. +------+---------------------------------------------------------------+--------------------------------+
    5. | 1 | NULL | NULL |
    6. | 2 | null | NULL |
    7. | 3 | true | NULL |
    8. | 4 | false | NULL |
    9. | 5 | 100 | 100 |
    10. | 6 | 10000 | 10000 |
    11. | 7 | 1000000000 | 1000000000 |
    12. | 8 | 1152921504606846976 | 1.152921504606847e+18 |
    13. | 9 | 6.18 | 6.18 |
    14. | 10 | "abcd" | NULL |
    15. | 11 | {} | NULL |
    16. | 12 | {"k1":"v31","k2":300} | NULL |
    17. | 14 | [123,456] | NULL |
    18. | 15 | ["abc","def"] | NULL |
    19. | 16 | [null,true,false,100,6.18,"abc"] | NULL |
    20. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL |
    21. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL |
    22. | 26 | {"k1":"v1","k2":200} | NULL |
    23. 19 rows in set (0.02 sec)
    24. mysql> SELECT id, j, jsonb_extract_double(j, '$.k2') FROM test_jsonb ORDER BY id;
    25. +------+---------------------------------------------------------------+-----------------------------------+
    26. | id | j | jsonb_extract_double(`j`, '$.k2') |
    27. +------+---------------------------------------------------------------+-----------------------------------+
    28. | 1 | NULL | NULL |
    29. | 2 | null | NULL |
    30. | 3 | true | NULL |
    31. | 4 | false | NULL |
    32. | 5 | 100 | NULL |
    33. | 6 | 10000 | NULL |
    34. | 7 | 1000000000 | NULL |
    35. | 8 | 1152921504606846976 | NULL |
    36. | 9 | 6.18 | NULL |
    37. | 10 | "abcd" | NULL |
    38. | 11 | {} | NULL |
    39. | 12 | {"k1":"v31","k2":300} | 300 |
    40. | 13 | [] | NULL |
    41. | 14 | [123,456] | NULL |
    42. | 15 | ["abc","def"] | NULL |
    43. | 16 | [null,true,false,100,6.18,"abc"] | NULL |
    44. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL |
    45. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 300 |
    46. | 26 | {"k1":"v1","k2":200} | 200 |
    47. +------+---------------------------------------------------------------+-----------------------------------+
    48. 19 rows in set (0.03 sec)
    • jsonb_extract_bool 获取bool类型字段,非bool类型返回NULL
    1. mysql> SELECT id, j, jsonb_extract_bool(j, '$') FROM test_jsonb ORDER BY id;
    2. +------+---------------------------------------------------------------+------------------------------+
    3. | id | j | jsonb_extract_bool(`j`, '$') |
    4. +------+---------------------------------------------------------------+------------------------------+
    5. | 1 | NULL | NULL |
    6. | 2 | null | NULL |
    7. | 3 | true | 1 |
    8. | 4 | false | 0 |
    9. | 5 | 100 | NULL |
    10. | 6 | 10000 | NULL |
    11. | 7 | 1000000000 | NULL |
    12. | 8 | 1152921504606846976 | NULL |
    13. | 9 | 6.18 | NULL |
    14. | 10 | "abcd" | NULL |
    15. | 11 | {} | NULL |
    16. | 12 | {"k1":"v31","k2":300} | NULL |
    17. | 13 | [] | NULL |
    18. | 14 | [123,456] | NULL |
    19. | 15 | ["abc","def"] | NULL |
    20. | 16 | [null,true,false,100,6.18,"abc"] | NULL |
    21. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL |
    22. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL |
    23. | 26 | {"k1":"v1","k2":200} | NULL |
    24. +------+---------------------------------------------------------------+------------------------------+
    25. 19 rows in set (0.01 sec)
    26. mysql> SELECT id, j, jsonb_extract_bool(j, '$[1]') FROM test_jsonb ORDER BY id;
    27. +------+---------------------------------------------------------------+---------------------------------+
    28. | id | j | jsonb_extract_bool(`j`, '$[1]') |
    29. +------+---------------------------------------------------------------+---------------------------------+
    30. | 1 | NULL | NULL |
    31. | 2 | null | NULL |
    32. | 3 | true | NULL |
    33. | 4 | false | NULL |
    34. | 5 | 100 | NULL |
    35. | 6 | 10000 | NULL |
    36. | 7 | 1000000000 | NULL |
    37. | 8 | 1152921504606846976 | NULL |
    38. | 9 | 6.18 | NULL |
    39. | 10 | "abcd" | NULL |
    40. | 11 | {} | NULL |
    41. | 12 | {"k1":"v31","k2":300} | NULL |
    42. | 13 | [] | NULL |
    43. | 14 | [123,456] | NULL |
    44. | 15 | ["abc","def"] | NULL |
    45. | 16 | [null,true,false,100,6.18,"abc"] | 1 |
    46. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | NULL |
    47. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | NULL |
    48. | 26 | {"k1":"v1","k2":200} | NULL |
    49. +------+---------------------------------------------------------------+---------------------------------+
    50. 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
    1. mysql> SELECT id, j, jsonb_extract_isnull(j, '$') FROM test_jsonb ORDER BY id;
    2. +------+---------------------------------------------------------------+--------------------------------+
    3. | id | j | jsonb_extract_isnull(`j`, '$') |
    4. +------+---------------------------------------------------------------+--------------------------------+
    5. | 1 | NULL | NULL |
    6. | 2 | null | 1 |
    7. | 3 | true | 0 |
    8. | 4 | false | 0 |
    9. | 5 | 100 | 0 |
    10. | 6 | 10000 | 0 |
    11. | 7 | 1000000000 | 0 |
    12. | 8 | 1152921504606846976 | 0 |
    13. | 9 | 6.18 | 0 |
    14. | 10 | "abcd" | 0 |
    15. | 11 | {} | 0 |
    16. | 12 | {"k1":"v31","k2":300} | 0 |
    17. | 13 | [] | 0 |
    18. | 14 | [123,456] | 0 |
    19. | 15 | ["abc","def"] | 0 |
    20. | 16 | [null,true,false,100,6.18,"abc"] | 0 |
    21. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 0 |
    22. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 0 |
    23. | 26 | {"k1":"v1","k2":200} | 0 |
    24. +------+---------------------------------------------------------------+--------------------------------+
    25. 19 rows in set (0.03 sec)
    用jsonb_exists_path检查json内的某个字段是否存在
    1. mysql> SELECT id, j, jsonb_exists_path(j, '$') FROM test_jsonb ORDER BY id;
    2. +------+---------------------------------------------------------------+-----------------------------+
    3. | id | j | jsonb_exists_path(`j`, '$') |
    4. +------+---------------------------------------------------------------+-----------------------------+
    5. | 1 | NULL | NULL |
    6. | 2 | null | 1 |
    7. | 3 | true | 1 |
    8. | 4 | false | 1 |
    9. | 5 | 100 | 1 |
    10. | 6 | 10000 | 1 |
    11. | 7 | 1000000000 | 1 |
    12. | 8 | 1152921504606846976 | 1 |
    13. | 9 | 6.18 | 1 |
    14. | 10 | "abcd" | 1 |
    15. | 11 | {} | 1 |
    16. | 12 | {"k1":"v31","k2":300} | 1 |
    17. | 13 | [] | 1 |
    18. | 14 | [123,456] | 1 |
    19. | 15 | ["abc","def"] | 1 |
    20. | 16 | [null,true,false,100,6.18,"abc"] | 1 |
    21. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 1 |
    22. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 1 |
    23. | 26 | {"k1":"v1","k2":200} | 1 |
    24. +------+---------------------------------------------------------------+-----------------------------+
    25. 19 rows in set (0.02 sec)
    26. mysql> SELECT id, j, jsonb_exists_path(j, '$.k1') FROM test_jsonb ORDER BY id;
    27. +------+---------------------------------------------------------------+--------------------------------+
    28. | id | j | jsonb_exists_path(`j`, '$.k1') |
    29. +------+---------------------------------------------------------------+--------------------------------+
    30. | 1 | NULL | NULL |
    31. | 2 | null | 0 |
    32. | 3 | true | 0 |
    33. | 4 | false | 0 |
    34. | 5 | 100 | 0 |
    35. | 6 | 10000 | 0 |
    36. | 7 | 1000000000 | 0 |
    37. | 8 | 1152921504606846976 | 0 |
    38. | 9 | 6.18 | 0 |
    39. | 10 | "abcd" | 0 |
    40. | 11 | {} | 0 |
    41. | 12 | {"k1":"v31","k2":300} | 1 |
    42. | 13 | [] | 0 |
    43. | 14 | [123,456] | 0 |
    44. | 15 | ["abc","def"] | 0 |
    45. | 16 | [null,true,false,100,6.18,"abc"] | 0 |
    46. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 0 |
    47. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 1 |
    48. | 26 | {"k1":"v1","k2":200} | 1 |
    49. +------+---------------------------------------------------------------+--------------------------------+
    50. 19 rows in set (0.03 sec)
    51. mysql> SELECT id, j, jsonb_exists_path(j, '$[2]') FROM test_jsonb ORDER BY id;
    52. +------+---------------------------------------------------------------+--------------------------------+
    53. | id | j | jsonb_exists_path(`j`, '$[2]') |
    54. +------+---------------------------------------------------------------+--------------------------------+
    55. | 1 | NULL | NULL |
    56. | 2 | null | 0 |
    57. | 3 | true | 0 |
    58. | 4 | false | 0 |
    59. | 5 | 100 | 0 |
    60. | 6 | 10000 | 0 |
    61. | 7 | 1000000000 | 0 |
    62. | 8 | 1152921504606846976 | 0 |
    63. | 9 | 6.18 | 0 |
    64. | 10 | "abcd" | 0 |
    65. | 11 | {} | 0 |
    66. | 12 | {"k1":"v31","k2":300} | 0 |
    67. | 13 | [] | 0 |
    68. | 14 | [123,456] | 0 |
    69. | 15 | ["abc","def"] | 0 |
    70. | 16 | [null,true,false,100,6.18,"abc"] | 1 |
    71. | 17 | [{"k1":"v41","k2":400},1,"a",3.14] | 1 |
    72. | 18 | {"k1":"v31","k2":300,"a1":[{"k1":"v41","k2":400},1,"a",3.14]} | 0 |
    73. | 26 | {"k1":"v1","k2":200} | 0 |
    用jsonb_type获取json内的某个字段的类型
    • 返回json path对应的json字段类型,如果不存在返回NULL