面試官:不會看 Explain執(zhí)行計劃,簡歷敢寫 SQL 優(yōu)化?
本文轉(zhuǎn)載自微信公眾號「程序員內(nèi)點事」,轉(zhuǎn)載本文請聯(lián)系公眾號。
昨天中午在食堂,和部門的技術(shù)大牛們坐在一桌吃飯,作為一個卑微技術(shù)渣仔默默的吃著飯,聽大佬們高談闊論,研究各種高端技術(shù),我TM也想說話可實在插不上嘴。
聊著聊著突然說到他上午面試了一個工作6年的程序員,表情挺復(fù)雜,他說:我看他簡歷寫著熟悉SQL語句調(diào)優(yōu),就問了下 Explain 執(zhí)行計劃怎么看?結(jié)果這老哥一問三不知,工作6年這么基礎(chǔ)的東西都不了解!
感受到了大佬的王之鄙視,回到工位我就開始默默寫這個,哎~ 我TM也不太懂 Explain,老哥你這是針對我啊!哭唧唧~
Explain有什么用
當Explain 與 SQL語句一起使用時,MySQL 會顯示來自優(yōu)化器關(guān)于SQL執(zhí)行的信息。也就是說,MySQL解釋了它將如何處理該語句,包括如何連接表以及什么順序連接表等。
- 表的加載順序
- sql 的查詢類型
- 可能用到哪些索引,哪些索引又被實際使用
- 表與表之間的引用關(guān)系
- 一個表中有多少行被優(yōu)化器查詢 .....
Explain有哪些信息
Explain 執(zhí)行計劃包含字段信息如下:分別是 id、select_type、table、partitions、type、possible_keys、key、key_len、ref、rows、filtered、Extra 12個字段。
下邊我們會結(jié)合具體的SQL示例,詳細的解讀每個字段以及每個字段中不同參數(shù)的含義,以下所有示例數(shù)據(jù)庫版本為 MySQL.5.7.17。
- mysql> select version() from dual;
- +------------+
- | version() |
- +------------+
- | 5.7.17-log |
- +------------+
我們創(chuàng)建三張表 one、two、three,表之間的關(guān)系 one.two_id = two.two_id AND two.three_id = three.three_id。
Explain執(zhí)行計劃詳解
一、id
id: :表示查詢中執(zhí)行select子句或者操作表的順序,id的值越大,代表優(yōu)先級越高,越先執(zhí)行。 id大致會出現(xiàn) 3種情況:
1、id相同
看到三條記錄的id都相同,可以理解成這三個表為一組,具有同樣的優(yōu)先級,執(zhí)行順序由上而下,具體順序由優(yōu)化器決定。
- mysql> EXPLAIN SELECT * FROM one o,two t, three r WHERE o.two_id = t.two_id AND t.three_id = r.three_id;
- +----+-------------+-------+------------+--------+---------------+---------+---------+----------------------+------+----------+----------------------------------------------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+--------+---------------+---------+---------+----------------------+------+----------+----------------------------------------------------+
- | 1 | SIMPLE | o | NULL | ALL | NULL | NULL | NULL | NULL | 2 | 100 | NULL |
- | 1 | SIMPLE | t | NULL | ALL | PRIMARY | NULL | NULL | NULL | 2 | 50 | Using where; Using join buffer (Block Nested Loop) |
- | 1 | SIMPLE | r | NULL | eq_ref | PRIMARY | PRIMARY | 4 | xin-slave.t.three_id | 1 | 100 | NULL |
- +----+-------------+-------+------------+--------+---------------+---------+---------+----------------------+------+----------+----------------------------------------------------+
2、id不同
如果我們的 SQL 中存在子查詢,那么 id的序號會遞增,id值越大優(yōu)先級越高,越先被執(zhí)行 。當三個表依次嵌套,發(fā)現(xiàn)最里層的子查詢 id最大,最先執(zhí)行。
- mysql> EXPLAIN select * from one o where o.two_id = (select t.two_id from two t where t.three_id = (select r.three_id from three r where r.three_name='我是第三表2'));
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
- | 1 | PRIMARY | o | NULL | ALL | NULL | NULL | NULL | NULL | 2 | 50 | Using where |
- | 2 | SUBQUERY | t | NULL | ALL | NULL | NULL | NULL | NULL | 2 | 50 | Using where |
- | 3 | SUBQUERY | r | NULL | ALL | NULL | NULL | NULL | NULL | 2 | 50 | Using where |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
3、以上兩種同時存在
將上邊的 SQL 稍微修改一下,增加一個子查詢,發(fā)現(xiàn) id的以上兩種同時存在。相同id劃分為一組,這樣就有三個組,同組的從上往下順序執(zhí)行,不同組 id值越大,優(yōu)先級越高,越先執(zhí)行。
- mysql> EXPLAIN select * from one o where o.two_id = (select t.two_id from two t where t.three_id = (select r.three_id from three r where r.three_name='我是第三表2')) AND o.one_id in(select one_id from one where o.one_name="我是第一表2");
- +----+-------------+-------+------------+--------+---------------+---------+---------+--------------------+------+----------+-------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+--------+---------------+---------+---------+--------------------+------+----------+-------------+
- | 1 | PRIMARY | o | NULL | ALL | PRIMARY | NULL | NULL | NULL | 2 | 50 | Using where |
- | 1 | PRIMARY | one | NULL | eq_ref | PRIMARY | PRIMARY | 4 | xin-slave.o.one_id | 1 | 100 | Using index |
- | 2 | SUBQUERY | t | NULL | ALL | NULL | NULL | NULL | NULL | 2 | 50 | Using where |
- | 3 | SUBQUERY | r | NULL | ALL | NULL | NULL | NULL | NULL | 2 | 50 | Using where |
- +----+-------------+-------+------------+--------+---------------+---------+---------+--------------------+------+----------+-------------+
二、select_type
select_type:表示 select 查詢的類型,主要是用于區(qū)分各種復(fù)雜的查詢,例如:普通查詢、聯(lián)合查詢、子查詢等。
1、SIMPLE
SIMPLE:表示最簡單的 select 查詢語句,也就是在查詢中不包含子查詢或者 union交并差集等操作。
2、PRIMARY
PRIMARY:當查詢語句中包含任何復(fù)雜的子部分,最外層查詢則被標記為PRIMARY。
3、SUBQUERY
SUBQUERY:當 select 或 where 列表中包含了子查詢,該子查詢被標記為:SUBQUERY 。
4、DERIVED
DERIVED:表示包含在from子句中的子查詢的select,在我們的 from 列表中包含的子查詢會被標記為derived 。
5、UNION
UNION:如果union后邊又出現(xiàn)的select 語句,則會被標記為union;若 union 包含在from 子句的子查詢中,外層 select 將被標記為 derived。
6、UNION RESULT
- mysql> EXPLAIN select t.two_name, ( select one.one_id from one) o from (select two_id,two_name from two where two_name ='') t union (select r.three_name,r.three_id from three r);
- +------+--------------+------------+------------+-------+---------------+---------+---------+------+------+----------+-----------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +------+--------------+------------+------------+-------+---------------+---------+---------+------+------+----------+-----------------+
- | 1 | PRIMARY | two | NULL | ALL | NULL | NULL | NULL | NULL | 2 | 50 | Using where |
- | 2 | SUBQUERY | one | NULL | index | NULL | PRIMARY | 4 | NULL | 2 | 100 | Using index |
- | 4 | UNION | r | NULL | ALL | NULL | NULL | NULL | NULL | 2 | 100 | NULL |
- | NULL | UNION RESULT | <union1,4> | NULL | ALL | NULL | NULL | NULL | NULL | NULL | NULL | Using temporary |
- +------+--------------+------------+------------+-------+---------------+---------+---------+------+------+---
三、table
查詢的表名,并不一定是真實存在的表,有別名顯示別名,也可能為臨時表,例如上邊的DERIVED、
四、partitions
查詢時匹配到的分區(qū)信息,對于非分區(qū)表值為NULL,當查詢的是分區(qū)表時,partitions顯示分區(qū)表命中的分區(qū)情況。
- +----+-------------+----------------+---------------------------------+-------+---------------+---------+---------+------+------+----------+-------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+----------------+---------------------------------+-------+---------------+---------+---------+------+------+----------+-------------+
- | 1 | SIMPLE | one | p201801,p201802,p201803,p300012 | index | NULL | PRIMARY | 9 | NULL | 3 | 100 | Using index |
- +----+-------------+----------------+---------------------------------+-------+---------------+---------+---------+------+------+----------+-------------+
五、type
type:查詢使用了何種類型,它在 SQL優(yōu)化中是一個非常重要的指標,以下性能從好到壞依次是:system > const > eq_ref > ref > ref_or_null > index_merge > unique_subquery > index_subquery > range > index > ALL
1、system
system: 當表僅有一行記錄時(系統(tǒng)表),數(shù)據(jù)量很少,往往不需要進行磁盤IO,速度非???。
2、const
- mysql> EXPLAIN SELECT * from three where three_id=1;
- +----+-------------+-------+------------+-------+---------------+---------+---------+-------+------+----------+-------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+-------+---------------+---------+---------+-------+------+----------+-------+
- | 1 | SIMPLE | three | NULL | const | PRIMARY | PRIMARY | 4 | const | 1 | 100 | NULL |
- +----+-------------+-------+------------+-------+---------------+---------+---------+-------+------+----------+-------+
3、eq_ref
eq_ref:查詢時命中主鍵primary key 或者 unique key索引, type 就是 eq_ref。
- mysql> EXPLAIN select o.one_name from one o ,two t where o.one_id = t.two_id ;
- +----+-------------+-------+------------+--------+---------------+----------+---------+--------------------+------+----------+-------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+--------+---------------+----------+---------+--------------------+------+----------+-------------+
- | 1 | SIMPLE | o | NULL | index | PRIMARY | idx_name | 768 | NULL | 2 | 100 | Using index |
- | 1 | SIMPLE | t | NULL | eq_ref | PRIMARY | PRIMARY | 4 | xin-slave.o.one_id | 1 | 100 | Using index |
- +----+-------------+-------+------------+--------+---------------+----------+---------+--------------------+------+----------+-------------+
4、ref
ref:區(qū)別于eq_ref ,ref表示使用非唯一性索引,會找到很多個符合條件的行。
- mysql> select o.one_id from one o where o.one_name = "xin" ;
- +--------+
- | one_id |
- +--------+
- | 1 |
- | 3 |
- +--------+```
- ```sql
- mysql> EXPLAIN select o.one_id from one o where o.one_name = "xin" ;
- +----+-------------+-------+------------+------+---------------+----------+---------+-------+------+----------+-------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+------+---------------+----------+---------+-------+------+----------+-------------+
- | 1 | SIMPLE | o | NULL | ref | idx_name | idx_name | 768 | const | 1 | 100 | Using index |
- +----+-------------+-------+------------+------+---------------+----------+---------+-------+------+-
5、ref_or_null
ref_or_null:這種連接類型類似于 ref,區(qū)別在于 MySQL會額外搜索包含NULL值的行。
- mysql> EXPLAIN select o.one_id from one o where o.one_name = "xin" OR o.one_name IS NULL;
- +----+-------------+-------+------------+-------------+---------------+----------+---------+-------+------+----------+--------------------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+-------------+---------------+----------+---------+-------+------+----------+--------------------------+
- | 1 | SIMPLE | o | NULL | ref_or_null | idx_name | idx_name | 768 | const | 3 | 100 | Using where; Using index |
- +----+-------------+-------+------------+-------------+---------------+----------+---------+-------+------+----------+--------------------------+
6、index_merge
index_merge:使用了索引合并優(yōu)化方法,查詢使用了兩個以上的索引。
- mysql> EXPLAIN select * from one o where o.one_id >1 and o.one_name ='xin';
- +----+-------------+-------+------------+-------------+------------------+------------------+---------+------+------+----------+------------------------------------------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+-------------+------------------+------------------+---------+------+------+----------+------------------------------------------------+
- | 1 | SIMPLE | o | NULL | index_merge | PRIMARY,idx_name | idx_name,PRIMARY | 772,4 | NULL | 1 | 100 | Using intersect(idx_name,PRIMARY); Using where |
- +----+-------------+-------+------------+-------------+------------------+------------------+---------+------+------+----------+------------------------------------------------+
7、unique_subquery
unique_subquery:替換下面的 IN子查詢,子查詢返回不重復(fù)的集合。
- value IN (SELECT primary_key FROM single_table WHERE some_expr)
8、index_subquery
index_subquery:區(qū)別于unique_subquery,用于非唯一索引,可以返回重復(fù)值。
- value IN (SELECT key_column FROM single_table WHERE some_expr)
9、range
range:使用索引選擇行,僅檢索給定范圍內(nèi)的行。簡單點說就是針對一個有索引的字段,給定范圍檢索數(shù)據(jù)。在where語句中使用 bettween...and、<、>、<=、in 等條件查詢 type 都是 range。
舉個栗子:three表中three_id為唯一主鍵,user_id普通字段未建索引。
- mysql> EXPLAIN SELECT * from three where three_id BETWEEN 2 AND 3;
- +----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
- | 1 | SIMPLE | three | NULL | range | PRIMARY | PRIMARY | 4 | NULL | 1 | 100 | Using where |
- +----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
從結(jié)果中看到只有對設(shè)置了索引的字段,做范圍檢索 type 才是 range。
- mysql> EXPLAIN SELECT * from three where user_id BETWEEN 2 AND 3;
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
- | 1 | SIMPLE | three | NULL | ALL | NULL | NULL | NULL | NULL | 3 | 33.33 | Using where |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
10、index
index:Index 與ALL 其實都是讀全表,區(qū)別在于index是遍歷索引樹讀取,而ALL是從硬盤中讀取。
下邊示例:three_id 為主鍵,不帶 where 條件全表查詢 ,type結(jié)果為index 。
- mysql> EXPLAIN SELECT three_id from three ;
- +----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
- | 1 | SIMPLE | three | NULL | index | NULL | PRIMARY | 4 | NULL | 1 | 100 | Using index |
- +----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
11、ALL
ALL:將遍歷全表以找到匹配的行,性能最差。
- mysql> EXPLAIN SELECT * from two ;
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------+
- | 1 | SIMPLE | two | NULL | ALL | NULL | NULL | NULL | NULL | 2 | 100 | NULL |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------+
六、possible_keys
possible_keys:表示在MySQL中通過哪些索引,能讓我們在表中找到想要的記錄,一旦查詢涉及到的某個字段上存在索引,則索引將被列出,但這個索引并不定一會是最終查詢數(shù)據(jù)時所被用到的索引。具體請參考上邊的例子。
七、key
key:區(qū)別于possible_keys,key是查詢中實際使用到的索引,若沒有使用索引,顯示為NULL。具體請參考上邊的例子。
當 type 為 index_merge 時,可能會顯示多個索引。
八、key_len
key_len:表示查詢用到的索引長度(字節(jié)數(shù)),原則上長度越短越好 。
- 單列索引,那么需要將整個索引長度算進去;
- 多列索引,不是所有列都能用到,需要計算查詢中實際用到的列。
注意:key_len只計算where條件中用到的索引長度,而排序和分組即便是用到了索引,也不會計算到key_len中。
九、ref
ref:常見的有:const,func,null,字段名。
- 當使用常量等值查詢,顯示const,
- 當關(guān)聯(lián)查詢時,會顯示相應(yīng)關(guān)聯(lián)表的關(guān)聯(lián)字段
- 如果查詢條件使用了表達式、函數(shù),或者條件列發(fā)生內(nèi)部隱式轉(zhuǎn)換,可能顯示為func
- 其他情況null
十、rows
rows:以表的統(tǒng)計信息和索引使用情況,估算要找到我們所需的記錄,需要讀取的行數(shù)。
這是評估SQL 性能的一個比較重要的數(shù)據(jù),mysql需要掃描的行數(shù),很直觀的顯示 SQL性能的好壞,一般情況下 rows 值越小越好。
- mysql> EXPLAIN SELECT * from three;
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------+
- | 1 | SIMPLE | three | NULL | ALL | NULL | NULL | NULL | NULL | 3 | 100 | NULL |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------+
十一、filtered
filtered 這個是一個百分比的值,表里符合條件的記錄數(shù)的百分比。簡單點說,這個字段表示存儲引擎返回的數(shù)據(jù)在經(jīng)過過濾后,剩下滿足條件的記錄數(shù)量的比例。
在MySQL.5.7版本以前想要顯示filtered需要使用explain extended命令。MySQL.5.7后,默認explain直接顯示partitions和filtered的信息。
十二、Extra
Extra :不適合在其他列中顯示的信息,Explain 中的很多額外的信息會在 Extra 字段顯示。
1、Using index
Using index:我們在相應(yīng)的 select 操作中使用了覆蓋索引,通俗一點講就是查詢的列被索引覆蓋,使用到覆蓋索引查詢速度會非常快,SQl優(yōu)化中理想的狀態(tài)。
什么又是覆蓋索引?
一條 SQL只需要通過索引就可以返回,我們所需要查詢的數(shù)據(jù)(一個或幾個字段),而不必通過二級索引,查到主鍵之后再通過主鍵查詢整行數(shù)據(jù)(select * )。
one_id表為主鍵
- mysql> EXPLAIN SELECT one_id from one ;
- +----+-------------+-------+------------+-------+---------------+------------+---------+------+------+----------+-------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+-------+---------------+------------+---------+------+------+----------+-------------+
- | 1 | SIMPLE | one | NULL | index | NULL | idx_two_id | 5 | NULL | 3 | 100 | Using index |
- +----+-------------+-------+------------+-------+---------------+------------+---------+------+------+----------+-------------+
注意:想要使用到覆蓋索引,我們在 select 時只取出需要的字段,不可select *,而且該字段建了索引。
- mysql> EXPLAIN SELECT * from one ;
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------+
- | 1 | SIMPLE | one | NULL | ALL | NULL | NULL | NULL | NULL | 3 | 100 | NULL |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------+
2、Using where
Using where:查詢時未找到可用的索引,進而通過where條件過濾獲取所需數(shù)據(jù),但要注意的是并不是所有帶where語句的查詢都會顯示Using where。
下邊示例create_time 并未用到索引,type 為 ALL,即MySQL通過全表掃描后再按where條件篩選數(shù)據(jù)。
- mysql> EXPLAIN SELECT one_name from one where create_time ='2020-05-18';
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
- | 1 | SIMPLE | one | NULL | ALL | NULL | NULL | NULL | NULL | 3 | 33.33 | Using where |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
3、Using temporary
Using temporary:表示查詢后結(jié)果需要使用臨時表來存儲,一般在排序或者分組查詢時用到。
- mysql> EXPLAIN SELECT one_name from one where one_id in (1,2) group by one_name;
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
- | 1 | SIMPLE | one | NULL | range| NULL | NULL | NULL | NULL | 3 | 33.33 | Using where; Using temporary; Using filesort |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
4、Using filesort
Using filesort:表示無法利用索引完成的排序操作,也就是ORDER BY的字段沒有索引,通常這樣的SQL都是需要優(yōu)化的。
- mysql> EXPLAIN SELECT one_id from one ORDER BY create_time;
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+----------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+----------------+
- | 1 | SIMPLE | one | NULL | ALL | NULL | NULL | NULL | NULL | 3 | 100 | Using filesort |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+----------------+
如果ORDER BY字段有索引就會用到覆蓋索引,相比執(zhí)行速度快很多。
- mysql> EXPLAIN SELECT one_id from one ORDER BY one_id;
- +----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
- | 1 | SIMPLE | one | NULL | index | NULL | PRIMARY | 4 | NULL | 3 | 100 | Using index |
- +----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
5、Using join buffer
Using join buffer:在我們聯(lián)表查詢的時候,如果表的連接條件沒有用到索引,需要有一個連接緩沖區(qū)來存儲中間結(jié)果。
先看一下有索引的情況:連接條件 one_name 、two_name 都用到索引。
- mysql> EXPLAIN SELECT one_name from one o,two t where o.one_name = t.two_name;
- +----+-------------+-------+------------+-------+---------------+----------+---------+----------------------+------+----------+--------------------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+-------+---------------+----------+---------+----------------------+------+----------+--------------------------+
- | 1 | SIMPLE | o | NULL | index | idx_name | idx_name | 768 | NULL | 3 | 100 | Using where; Using index |
- | 1 | SIMPLE | t | NULL | ref | idx_name | idx_name | 768 | xin-slave.o.one_name | 1 | 100 | Using index |
- +----+-------------+-------+------------+-------+---------------+----------+---------+----------------------+------+----------+--------------------------+
接下來刪掉 連接條件 one_name 、two_name 的字段索引。發(fā)現(xiàn)Extra 列變成 Using join buffer,type均為全表掃描,這也是SQL優(yōu)化中需要注意的地方。
- mysql> EXPLAIN SELECT one_name from one o,two t where o.one_name = t.two_name;
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+----------------------------------------------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+----------------------------------------------------+
- | 1 | SIMPLE | t | NULL | ALL | NULL | NULL | NULL | NULL | 2 | 100 | NULL |
- | 1 | SIMPLE | o | NULL | ALL | NULL | NULL | NULL | NULL | 3 | 33.33 | Using where; Using join buffer (Block Nested Loop) |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+----------------------------------------------------+
6、Impossible where
Impossible where:表示在我們用不太正確的where語句,導(dǎo)致沒有符合條件的行。
- mysql> EXPLAIN SELECT one_name from one WHERE 1=2;
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+------------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+------------------+
- | 1 | SIMPLE | NULL | NULL | NULL | NULL | NULL | NULL | NULL | NULL | NULL | Impossible WHERE |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+------------------+
7、No tables used
No tables used:我們的查詢語句中沒有FROM子句,或者有 FROM DUAL子句。
- mysql> EXPLAIN select now();
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+----------------+
- | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+----------------+
- | 1 | SIMPLE | NULL | NULL | NULL | NULL | NULL | NULL | NULL | NULL | NULL | No tables used |
- +----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+----------------+
Extra列的信息非常非常多,這里就不再一一列舉了,詳見 MySQL官方文檔 :https://dev.mysql.com/doc/refman/5.7/en/explain-output.html#jointype_index_merge
總結(jié)
上邊只是簡單介紹了下 Explain 執(zhí)行計劃各個列的含義,了解它不僅僅是要應(yīng)付面試,在實際開發(fā)中也經(jīng)常會用到。比如對慢SQL進行分析,如果連執(zhí)行計劃結(jié)果都不會看,那還談什么SQL優(yōu)化呢?