MySQL“自古以来”都有一个神秘的HANDLER命令,而此命令非SQL标准语法,可以降低优化器对于SQL语句的解析与优化开销,从而提升查询性能。看到这里,可能有小伙伴不淡定了,这么好的东西为啥没广泛使用呢?这不是与几年前很夯的handlersocket插件类似吗?
那么,我们先来看看Handler语法说明:
HANDLER tbl_name OPEN [ [AS] alias]
HANDLER tbl_name READ index_name { = | <= | >= | < | > } (value1,value2,…) [ WHERE where_condition ] [LIMIT … ]HANDLER tbl_name READ index_name { FIRST | NEXT | PREV | LAST } [ WHERE where_condition ] [LIMIT … ]HANDLER tbl_name READ { FIRST | NEXT } [ WHERE where_condition ] [LIMIT … ] //主健,无索引指定HANDLER tbl_name CLOSE
首先从语法上看,HANDLER可以通过指定的索引去访问数据。但此语法并不支持DML操作。此外,由于减少了SQL解析,Handler命令的性能真的非常不错,根据Inside君的简单主键测试,Handler命令比SQL要快40%~45%。测试脚本如下:
SET @id=FLOOR(RAND()*1000000);
HANDLER sbtest.sbtest1 OPEN AS c;HANDLER C READ `PRIMARY` = (@id);HANDLER C CLOSE;
mysql> select * from test.test ;+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 1 | abc | 2016-07-18 23:44:05 || 2 | abc | 2016-07-18 23:44:05 || 3 | abd | 2016-07-18 23:44:05 || 4 | acd | 2016-07-18 23:44:05 || 5 | def | 2016-07-18 23:44:05 || 6 | pqr | 2016-07-18 23:44:05 || 7 | stu | 2016-07-18 23:44:05 || 8 | vwx | 2016-07-18 23:44:05 || 9 | yza | 2016-07-18 23:44:05 || 10 | def | 2016-07-18 23:44:05 |+----+------+---------------------+10 rows in set (0.01 sec)
CREATE TABLE `test` ( `id` int(10) unsigned NOT NULL AUTO_INCREMENT, `data` varchar(32) DEFAULT NULL, `ts` timestamp NULL DEFAULT NULL, PRIMARY KEY (`id`), KEY `data` (`data`)) ENGINE=InnoDB AUTO_INCREMENT=11 DEFAULT CHARSET=gbk
mysql> handler test.test open as c; //打开Query OK, 0 rows affected (0.01 sec) mysql> handler c read `PRIMARY`=(5); //查询主健+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 5 | def | 2016-07-18 23:44:05 |+----+------+---------------------+1 row in set (0.00 sec)mysql> handler c close; //关闭Query OK, 0 rows affected (0.00 sec)
mysql> handler test.test open; //openQuery OK, 0 rows affected (0.00 sec)mysql> handler test read data first; //data索引,第一个记录+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 1 | abc | 2016-07-18 23:44:05 |+----+------+---------------------+1 row in set (0.00 sec)mysql> handler test read data next; //下一个记录+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 2 | abc | 2016-07-18 23:44:05 |+----+------+---------------------+1 row in set (0.00 sec)mysql> handler test read data prev; //前一个记录+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 1 | abc | 2016-07-18 23:44:05 |+----+------+---------------------+1 row in set (0.01 sec)mysql> handler test read data last; //最后一条记录+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 9 | yza | 2016-07-18 23:44:05 |+----+------+---------------------+1 row in set (0.00 sec)
mysql> handler test read `data`=("yza");+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 9 | yza | 2016-07-18 23:44:05 |+----+------+---------------------+1 row in set (0.01 sec)
mysql> handler test read data=("abc") limit 5;+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 1 | abc | 2016-07-18 23:44:05 || 2 | abc | 2016-07-18 23:44:05 |+----+------+---------------------+2 rows in set (0.00 sec)
mysql> handler test read first limit 2; //头两个记录 ID索引+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 1 | abc | 2016-07-18 23:44:05 || 2 | abc | 2016-07-18 23:44:05 |+----+------+---------------------+2 rows in set (0.00 sec)mysql> handler test read first limit 3;+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 1 | abc | 2016-07-18 23:44:05 || 2 | abc | 2016-07-18 23:44:05 || 3 | abd | 2016-07-18 23:44:05 |+----+------+---------------------+3 rows in set (0.15 sec)mysql> handler test read first ;+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 1 | abc | 2016-07-18 23:44:05 |+----+------+---------------------+1 row in set (0.00 sec)
mysql> handler test read data last limit 5; //data索引+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 9 | yza | 2016-07-18 23:44:05 || 8 | vwx | 2016-07-18 23:44:05 || 7 | stu | 2016-07-18 23:44:05 || 6 | pqr | 2016-07-18 23:44:05 || 10 | def | 2016-07-18 23:44:05 |+----+------+---------------------+5 rows in set (0.00 sec)
Handler_read_first :
mysql> flush status;Query OK, 0 rows affected (0.00 sec)mysql> show session status like "%handler%";+----------------------------+-------+| Variable_name | Value |+----------------------------+-------+| Handler_commit | 0 || Handler_delete | 0 || Handler_discover | 0 || Handler_external_lock | 0 || Handler_mrr_init | 0 || Handler_prepare | 0 || Handler_read_first | 0 || Handler_read_key | 0 || Handler_read_last | 0 || Handler_read_next | 0 || Handler_read_prev | 0 || Handler_read_rnd | 0 || Handler_read_rnd_next | 0 || Handler_rollback | 0 || Handler_savepoint | 0 || Handler_savepoint_rollback | 0 || Handler_update | 0 || Handler_write | 0 |+----------------------------+-------+18 rows in set (0.03 sec)mysql> handler test read data first;+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 1 | abc | 2016-07-18 23:44:05 |+----+------+---------------------+1 row in set (0.00 sec)mysql> show session status like "%handler%";+----------------------------+-------+| Variable_name | Value |+----------------------------+-------+| Handler_commit | 1 || Handler_delete | 0 || Handler_discover | 0 || Handler_external_lock | 2 || Handler_mrr_init | 0 || Handler_prepare | 0 || Handler_read_first | 1 || Handler_read_key | 1 || Handler_read_last | 0 || Handler_read_next | 0 || Handler_read_prev | 0 || Handler_read_rnd | 0 || Handler_read_rnd_next | 0 || Handler_rollback | 0 || Handler_savepoint | 0 || Handler_savepoint_rollback | 0 || Handler_update | 0 || Handler_write | 0 |+----------------------------+-------+18 rows in set (0.02 sec)mysql> handler test read data first;+----+------+---------------------+| id | data | ts |+----+------+---------------------+| 1 | abc | 2016-07-18 23:44:05 |+----+------+---------------------+1 row in set (0.07 sec)mysql> show session status like "%handler%";+----------------------------+-------+| Variable_name | Value |+----------------------------+-------+| Handler_commit | 2 || Handler_delete | 0 || Handler_discover | 0 || Handler_external_lock | 4 || Handler_mrr_init | 0 || Handler_prepare | 0 || Handler_read_first | 2 || Handler_read_key | 2 || Handler_read_last | 0 || Handler_read_next | 0 || Handler_read_prev | 0 || Handler_read_rnd | 0 || Handler_read_rnd_next | 0 || Handler_rollback | 0 || Handler_savepoint | 0 || Handler_savepoint_rollback | 0 || Handler_update | 0 || Handler_write | 0 |+----------------------------+-------+18 rows in set (0.03 sec)
在Inside君的24C的测试服务器上,64线程主键查询跑到了近37W QPS,还是非常令人印象深刻的。对比SQL的SELECT查询,整体测试结果如下图所示:
命令HANDLER的主要实现在源码sql_handler.h、sql_handler.cc,设个断点就能观察到具体的流程。MySQL上层及InnoDB存储引擎层主要实现函数入口为:
- Sql_cmd_handler_open::execute
- Sql_cmd_handler_read::execute
- Sql_cmd_handler_close::execute
- ha_innobase::init_table_handle_for_HANDLER
- ha_partition::init_table_handle_for_HANDLER()(7版本支持HANDLER操作分区表)
既然性能不错,为什么在生产环境中并不见到命令HANDLER的使用呢?主要是因为HANDLER命令存在以下几个主要问题:
- 非一致性读取???
- 返回聚集索引中的所有列(即使是二级索引访问),而不能返回某个具体列
- 二级索引不使用LIMIT关键字,只能返回1行记录
知道命令HANDLER的同学,可能会认为HANDLER读取存在脏读问题。因为MySQL官方文档对于HANDLER读取的说明就是这么说的:
The handler interface does not have to provide a consistent look of the data (for example, are permitted), so the storage engine can use optimizations that does not normally permit. |
然而需要特别注意的是,MySQL文档中准确的说法是可以允许提供不一致的读取。但InnoDB存储引擎的HANDLER实现是支持一致性读取的,Inside君亲测的确不存在脏读问题。当然,源码说明一切,可以发现在函数init_table_handle_for_HANDLER会对READVIEW进行分配,而注释也说明了这点:
/* We let HANDLER always to do the reads as consistent reads, evenif the trx isolation level would have been specified as SERIALIZABLE */m_prebuilt->select_lock_type = LOCK_NONE;m_prebuilt->stored_select_lock_type = LOCK_NONE; |
貌似用HANDLER命令来做主键的查询是不错的,减少了SQL解析器的开销,性能提升杠杠的。但为此,应用要付出巨大的改动,而SQL最大的优势就在于标准化。相信这也是目前NoSQL数据库遇到的最大的一个问题。比如MongoDB,Inside君每次写查询时都要打开官方的命令对照表……