mysql中json_extract的使用方法
前言
- mysql5.7版本开始支持JSON类型字段,本文详细介绍json_extract函数如何获取mysql中的JSON类型数据
- json_extract可以完全简写为 ->
- json_unquote(json_extract())可以完全简写为 ->>
- 下面介绍中大部分会利用简写
创建示例表
-
CREATE TABLE `test_json` ( `id` int(11) NOT NULL AUTO_INCREMENT, `content` json DEFAULT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB AUTO_INCREMENT=3 DEFAULT CHARSET=utf8mb4;
-
# 插入两条测试用的记录 INSERT INTO `test_json` (`content`) VALUES ('{"name":"tom","age":18,"score":[100,90,87],"address":{"province":"湖南","city":"长沙"}}'); INSERT INTO `test_json` (`content`) VALUES ('[1, "apple", "red", {"age": 18, "name": "tom"}]');
-
id content 1 {“age”: 18, “name”: “tom”, “score”: [100, 90, 87], “address”: {“city”: “长沙”, “province”: “湖南”}} 2 [1, “apple”, “red”, {“age”: 18, “name”: “tom”}]
基本语法
-
获取JSON对象中某个key对应的value值
-
json_extract函数中,第一个参数content表示json数据,第二个参数为json路径,其中
表示该
j
s
o
n
数据本身,
表示该json数据本身,
表示该json数据本身,.name就表示获取json中key为name的value值
-
可以利用 -> 表达式来代替json_extract
-
若获取的val本身为字符串,那么获取的val会被引号包起来,比如”tom”,这种数据被解析到程序对象中时,可能会被转义为“tom”。为了解决这个问题了,可以在外面再包上一层json_unquote函数,或者使用 ->> 代替->
-
content: {“age”: 18, “name”: “tom”, “score”: [100, 90, 87], “address”: {“city”: “长沙”, “province”: “湖南”}}
-
# 得到"tom" select json_extract(content,'$.name') from test_json where id = 1; # 简写方式:字段名->表达式等价于json_extract(字段名,表达式) select content->'$.name' from test_json where id = 1; # 结果: +--------------------------------+ | json_extract(content,'$.name') | +--------------------------------+ | "tom" | +--------------------------------+ +-------------------+ | content->'$.name' | +-------------------+ | "tom" | +-------------------+ # 解除双引号,得到tom select json_unquote(json_extract(content,'$.name')) from test_json where id = 1; # 简写方式:字段名->>表达式等价于json_unquote(json_extract(字段名,表达式)) select content->>'$.name' from test_json where id = 1; # 结果: +----------------------------------------------+ | json_unquote(json_extract(content,'$.name')) | +----------------------------------------------+ | tom | +----------------------------------------------+ +--------------------+ | content->>'$.name' | +--------------------+ | tom | +--------------------+
-
获取JSON数组中某个元素
-
json_extract函数中,第一个参数content表示json数据,第二个参数为json路径,其中
表示该
j
s
o
n
数据本身,
表示该json数据本身,
表示该json数据本身,[i]表示获取该json数组索引为i的元素(索引从0开始)
-
与获取key-val一样,若获取的元素为字符串,默认的方式也会得到双引号包起来的字符,导致程序转义,方法也是利用json_unquote函数,或者使用 ->> 代替->
-
content: [1, “apple”, “red”, {“age”: 18, “name”: “tom”}]
-
# 得到"apple" select json_extract(content,'$[1]') from test_json where id = 2; # 简写,效果同上 select content->'$[1]' from test_json where id = 2; # 结果: +------------------------------+ | json_extract(content,'$[1]') | +------------------------------+ | "apple" | +------------------------------+ +-----------------+ | content->'$[1]' | +-----------------+ | "apple" | +-----------------+ # 解除双引号,得到apple select json_unquote(json_extract(content,'$[1]')) from test_json where id = 2; # 简写,效果同上 select content->>'$[1]' from test_json where id = 2; # 结果: +--------------------------------------------+ | json_unquote(json_extract(content,'$[1]')) | +--------------------------------------------+ | apple | +--------------------------------------------+ +------------------+ | content->>'$[1]' | +------------------+ | apple | +------------------+
-
获取JSON中的嵌套数据
-
结合前面介绍的两种获取方式,可以获取json数据中的嵌套数据
-
content: id=1 {“age”: 18, “name”: “tom”, “score”: [100, 90, 87], “address”: {“city”: “长沙”, “province”: “湖南”}} content: id=2 [1, “apple”, “red”, {“age”: 18, “name”: “tom”}]
-
# 得到:87 select content->'$.score[2]' from test_json where id = 1; # 结果: +-----------------------+ | content->'$.score[2]' | +-----------------------+ | 87 | +-----------------------+ # 得到:18 select content->'$[3].age' from test_json where id = 2; # 结果: +---------------------+ | content->'$[3].age' | +---------------------+ | 18 | +---------------------+
渐入佳境
-
获取JSON多个路径的数据
-
将会把多个路径的数据组合成数组返回
-
content: id=1 {“age”: 18, “name”: “tom”, “score”: [100, 90, 87], “address”: {“city”: “长沙”, “province”: “湖南”}}
-
select json_extract(content,'$.age','$.score') from test_json where id = 1; # 结果: +-----------------------------------------+ | json_extract(content,'$.age','$.score') | +-----------------------------------------+ | [18, [100, 90, 87]] | +-----------------------------------------+ select json_extract(content,'$.name','$.address.province','$.address.city') from test_json where id = 1; # 结果: +----------------------------------------------------------------------+ | json_extract(content,'$.name','$.address.province','$.address.city') | +----------------------------------------------------------------------+ | ["tom", "湖南", "长沙"] | +----------------------------------------------------------------------+
-
路径表达式*的使用
-
将会把多个路径的数据组合成数组返回
-
# 先插入一条用于测试的数据 INSERT INTO `test_json` (`id`,`content`) VALUES(3,'{"name":"tom","address":{"name":"中央公园","city":"长沙"},"class":{"id":3,"name":"一年三班"},"friend":[{"age":20,"name":"marry"},{"age":21,"name":"Bob"}]}')
-
content: id=3 {“name”: “tom”, “class”: {“id”: 3, “name”: “一年三班”}, “friend”: [{“age”: 20, “name”: “marry”}, {“age”: 21, “name”: “Bob”}], “address”: {“city”: “长沙”, “name”: “中央公园”}}
-
# 获取所有二级嵌套中key=name的值 # 由于friend的二级嵌套是一个数组,所以.name获取不到其中的所有name值 select content->'$.*.name' from test_json where id = 3; +----------------------------------+ | content->'$.*.name' | +----------------------------------+ | ["一年三班", "中央公园"] | +----------------------------------+``` # 获取所有key为name值的数据,包括任何嵌套内的name select content->'$**.name' from test_json where id = 3; +---------------------------------------------------------+ | content->'$**.name' | +---------------------------------------------------------+ | ["tom", "一年三班", "marry", "Bob", "中央公园"] | +---------------------------------------------------------+ # 获取数组中所有的name值 select content->'$.friend[*].name' from test_json where id = 3; +-----------------------------+ | content->'$.friend[*].name' | +-----------------------------+ | ["marry", "Bob"] | +-----------------------------+
-
返回NULL值
-
content: id=1 {“age”: 18, “name”: “tom”, “score”: [100, 90, 87], “address”: {“city”: “长沙”, “province”: “湖南”}}
-
寻找的JSON路径都不存在
-
# age路径不存在,返回NULL # 若有多个路径,只要有一个路径存在则不会返回NULL select json_extract(content,'$.price') from test_json where id = 1; +---------------------------------+ | json_extract(content,'$.price') | +---------------------------------+ | NULL | +---------------------------------+
-
路径中有NULL
-
# 存在任意路径为NULL则返回NULL select json_extract(content,'$.age',NULL) from test_json where id = 1; +------------------------------------+ | json_extract(content,'$.age',NULL) | +------------------------------------+ | NULL | +------------------------------------+
-
返回错误
-
若第一个参数不是JSON类型的数据,则返回错误
-
select json_extract('{1,2]',$[0])
-
若路径表达式不规范,则返回错误
-
select content->'$age' from test_json where id = 1; # 结果: ERROR 3143 (42000): Invalid JSON path expression. The error is around character position 1.
使用场景
- JSON_EXTRACT函数通常用于要获取JSON中某个特定的数据或者要根据它作为判断条件时使用