mysql56> show create table cards\G *************************** 1. row *************************** Table: cards Create Table: CREATE TABLE `cards` ( `seq` bigint(20) unsigned NOT NULL AUTO_INCREMENT, `suite` varchar(6) NOT NULL, `number` tinyint(3) unsigned NOT NULL, UNIQUE KEY `seq` (`seq`), KEY `suite` (`suite`) ) ENGINE=InnoDB AUTO_INCREMENT=101 DEFAULT CHARSET=utf8 1 row in set (0.00 sec) mysql56> SELECT * FROM cards ORDER BY _rowid LIMIT 3; +-----+--------------+--------+ | seq | suite | number | +-----+--------------+--------+ | 1 | ダイヤ | 2 | | 2 | クラブ | 9 | | 3 | スペード | 3 | +-----+--------------+--------+ 3 rows in set (0.01 sec)
WHERE句だけをインデックスで解決するクエリーをEXPLAIN取ると
mysql56> explain extended SELECT * FROM cards WHERE suite= 'ハート' ORDER BY number; +----+-------------+-------+------+---------------+-------+---------+-------+------+----------+----------------------------------------------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | filtered | Extra | +----+-------------+-------+------+---------------+-------+---------+-------+------+----------+----------------------------------------------------+ | 1 | SIMPLE | cards | ref | suite | suite | 20 | const | 31 | 100.00 | Using index condition; Using where; Using filesort | +----+-------------+-------+------+---------------+-------+---------+-------+------+----------+----------------------------------------------------+ 1 row in set, 1 warning (0.00 sec) mysql56> SELECT * FROM cards WHERE suite= 'ハート' ORDER BY number; .. 31 rows in set (0.00 sec) mysql56> 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 | 0 | | Handler_read_key | 1 | | Handler_read_last | 0 | | Handler_read_next | 31 | | 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.00 sec)
こんな風になるじゃないですか。31行をインデックスからフェッチしてUsing filesort。
それはいいんですが、インデックスだけでWHERE句を解決しているにも関わらずUsing whereが出るし、filteredは100.00以外の値を見た記憶がない。これ5.5からずっとそうだったし、バグなのか仕様なのかよくわからない。
これが5.7では、
mysql57> explain extended SELECT * FROM cards WHERE suite= 'ハート' ORDER BY number; +----+-------------+-------+------------+------+---------------+-----------+---------+-------+------+----------+---------------------------------------+ | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra | +----+-------------+-------+------------+------+---------------+-----------+---------+-------+------+----------+---------------------------------------+ | 1 | SIMPLE | cards | NULL | ref | idx_suite | idx_suite | 17 | const | 100 | 31.00 | Using index condition; Using filesort | +----+-------------+-------+------------+------+---------------+-----------+---------+-------+------+----------+---------------------------------------+ 1 row in set, 2 warnings (0.00 sec) mysql57> SELECT * FROM cards WHERE suite= 'ハート' ORDER BY number; .. 31 rows in set (0.00 sec) mysql57> 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 | 0 | | Handler_read_key | 1 | | Handler_read_last | 0 | | Handler_read_next | 31 | | 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.00 sec)
こうなってました。
テーブル全体がrowsの100件で、31.00%がフィルターされてってことなんでしょうかね? 変なUsing whereは姿を見せなくなっています。
とはいえなんかこのfilteredカラム、ちょっと謎で、インデックスだけで解決できないクエリーにすると
mysql57> explain extended SELECT * FROM cards WHERE suite = 'ハート' AND number = 1 ORDER BY number; +----+-------------+-------+------------+------+---------------+-----------+---------+-------+------+----------+-------------+ | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra | +----+-------------+-------+------------+------+---------------+-----------+---------+-------+------+----------+-------------+ | 1 | SIMPLE | cards | NULL | ref | idx_suite | idx_suite | 17 | const | 31 | 10.00 | Using where | +----+-------------+-------+------------+------+---------------+-----------+---------+-------+------+----------+-------------+ 1 row in set, 2 warnings (0.00 sec) mysql57> SELECT * FROM cards WHERE suite = 'ハート' AND number = 1 ORDER BY number; +-----+-----------+--------+ | seq | suite | number | +-----+-----------+--------+ | 41 | ハート | 1 | | 47 | ハート | 1 | | 50 | ハート | 1 | | 59 | ハート | 1 | | 96 | ハート | 1 | +-----+-----------+--------+ 5 rows in set (0.00 sec)
rows= インデックスで解決できた31件、filterd= 10.00%は31 * 10.00% < 5とちょっと誤差が大きすぎる気がします。どうやって計算してるんだろ。
0 件のコメント :
コメントを投稿