MySQL 5.7 对json的支持
最近有个业务需要能够存储Json并做一些简单的业务逻辑处理。业务找到我说json的数据分析很难用mysql 5.6 ,这样的纯粹行存来处理难度很大,问我有没啥办法。
我第一想到的是mongodb,第二想到的就是mysql 5.7 。 然后一查,哎呀,已经GA了。 众所周知的,mongodb的引擎层的稳定性一直是短板,而innodb经过10年的验证,已经是非常稳定的东西了。
所以就在想,是不是可以试试mysql 5.7 , 简单尝试,发现mysql 5.7 + DRDS ,完全不带mongoDB玩啊。。。
看看我的简单功能测试:
create table json_test ( uid int auto_increment,data json,primary key(uid))engine=innodb;
建库
mysql> insert into json_test values (NULL, '{"name":"name1","mobile":"15044447279","amount":400}');
Query OK, 1 row affected (0.01 sec)
mysql> insert into json_test values (NULL, '{"name":"name1","mobile":"15044447279","amount":300}');
Query OK, 1 row affected (0.01 sec)
mysql> insert into json_test values (NULL, '{"name":"name2","mobile":"15044447278","amount":300}');
Query OK, 1 row affected (0.01 sec)
mysql> insert into json_test values (NULL, '{"name":"name3","mobile":"15044447277","amount":300}');
Query OK, 1 row affected (0.01 sec)
插入四条语句
mysql> select data from json_test;
+-----------------------------------------------------------+
| data |
+-----------------------------------------------------------+
| {"name": "name1", "amount": 400, "mobile": "15044447279"} |
| {"name": "name1", "amount": 300, "mobile": "15044447279"} |
| {"name": "name2", "amount": 300, "mobile": "15044447278"} |
| {"name": "name3", "amount": 300, "mobile": "15044447277"} |
+-----------------------------------------------------------+
查询这四条json语句
mysql> select data->"$.name" as name ,sum(data->"$.amount") from json_test group by name;
+---------+-----------------------+
| name | sum(data->"$.amount") |
+---------+-----------------------+
| "name1" | 700 |
| "name2" | 300 |
| "name3" | 300 |
+---------+-----------------------+
做个group by sum 常见的统计操作
insert into json_test values (NULL, '{"mobile":"15044447277","amount":300}');
插入一个不带name的数据,看看索引对空数据的兼容性情况。
mysql> ALTER TABLE json_test ADD user_name varchar(128) GENERATED ALWAYS AS (json_extract(data,'$.name')) VIRTUAL;
Query OK, 0 rows affected (0.05 sec)
Records: 0 Duplicates: 0 Warnings: 0
mysql> alter table json_test add index idx_username (user_name);
Query OK, 0 rows affected (0.04 sec)
Records: 0 Duplicates: 0 Warnings: 0
创建虚拟列并建立索引
mysql> select user_name,sum(data->"$.amount") from json_test where user_name = '"name1"';
+-----------+-----------------------+
| user_name | sum(data->"$.amount") |
+-----------+-----------------------+
| "name1" | 700 |
+-----------+-----------------------+
查看符合某个user_name的数据的sum。
mysql> explain select user_name,sum(data->"$.amount") from json_test where user_name = '"name1"';
+----+-------------+-----------+------------+------+---------------+--------------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-----------+------------+------+---------------+--------------+---------+-------+------+----------+-------+
| 1 | SIMPLE | json_test | NULL | ref | idx_username | idx_username | 131 | const | 2 | 100.00 | NULL |
+----+-------------+-----------+------------+------+---------------+--------------+---------+-------+------+----------+-------+
确认带索引数据走到了索引上
===========
然后,这东西竟然还支持事务。。这个就牛逼大了。。
mysql> start transaction;
Query OK, 0 rows affected (0.00 sec)
开启事务
mysql> select * from json_test;
+-----+-------------------------------------------------------------------+-----------+
| uid | data | user_name |
+-----+-------------------------------------------------------------------+-----------+
| 1 | {"name": "name1", "amount": 400, "mobile": "15044447279"} | "name1" |
| 2 | {"name": "name1", "amount": 300, "mobile": "15044447279"} | "name1" |
| 3 | {"name": "name2", "amount": 300, "mobile": "15044447278"} | "name2" |
| 4 | {"name": "name3", "amount": 300, "mobile": "15044447277"} | "name3" |
| 5 | {"amount": 300, "mobile": "15044447277"} | NULL |
| 6 | {"amount": "300", "name”:”name2”,”mobile": "15044447278"} | NULL |
+-----+-------------------------------------------------------------------+-----------+
查看原表。
mysql> insert into json_test (uid,data) values (NULL, '{"name":"name1","mobile":"15044447279","amount":300}');
Query OK, 1 row affected (0.00 sec)
插入新数据
mysql> select * from json_test; +-----+-------------------------------------------------------------------+-----------+
| uid | data | user_name |
+-----+-------------------------------------------------------------------+-----------+
| 1 | {"name": "name1", "amount": 400, "mobile": "15044447279"} | "name1" |
| 2 | {"name": "name1", "amount": 300, "mobile": "15044447279"} | "name1" |
| 3 | {"name": "name2", "amount": 300, "mobile": "15044447278"} | "name2" |
| 4 | {"name": "name3", "amount": 300, "mobile": "15044447277"} | "name3" |
| 5 | {"amount": 300, "mobile": "15044447277"} | NULL |
| 6 | {"amount": "300", "name”:”name2”,”mobile": "15044447278"} | NULL |
| 7 | {"name": "name1", "amount": 300, "mobile": "15044447279"} | "name1" |
+-----+-------------------------------------------------------------------+-----------+
7 rows in set (0.00 sec)
确认新数据
mysql> rollback;
回滚数据
mysql> select * from json_test;
+-----+-------------------------------------------------------------------+-----------+
| uid | data | user_name |
+-----+-------------------------------------------------------------------+-----------+
| 1 | {"name": "name1", "amount": 400, "mobile": "15044447279"} | "name1" |
| 2 | {"name": "name1", "amount": 300, "mobile": "15044447279"} | "name1" |
| 3 | {"name": "name2", "amount": 300, "mobile": "15044447278"} | "name2" |
| 4 | {"name": "name3", "amount": 300, "mobile": "15044447277"} | "name3" |
| 5 | {"amount": 300, "mobile": "15044447277"} | NULL |
| 6 | {"amount": "300", "name”:”name2”,”mobile": "15044447278"} | NULL |
+-----+-------------------------------------------------------------------+-----------+
6 rows in set (0.00 sec)
对mysql 5.7 好感度*2啊。。卧槽。
猜测一下虚拟列的做法:
ALTER TABLE json_test ADD user_name varchar(128) GENERATED ALWAYS AS (json_extract(data,'$.name')) VIRTUAL;
应该写入的时候做一个trigger 每个json都运算json_extract(data,'$.name') ,然后写到一个新的不可修改的列里。
这个就可以让原来的行存和文档有一个非常完美的结合,当业务变化大的时候,放到json里面,而当变化稳定下来,就迁移到行存里。
完美。 推荐!