分析MySQL中索引引引發(fā)的CPU負(fù)載飆升的問題
收到一個mysql服務(wù)器負(fù)載告警,上去一看,load average都飆到280多了,用top一看,CPU跑到了336%,不過IO和內(nèi)存的負(fù)載并不高,根據(jù)經(jīng)驗(yàn),應(yīng)該又是一起索引引起的慘案了。
看下processlist以及slow query情況,發(fā)現(xiàn)有一個SQL經(jīng)常出現(xiàn),執(zhí)行計劃中的掃描記錄數(shù)看著還可以,單次執(zhí)行耗時為0.07s,還不算太大。乍一看,可能不是它引發(fā)的,但出現(xiàn)頻率實(shí)在太高,而且執(zhí)行計劃看起來也不夠完美:
mysql> explain SELECT count(1) FROM a , b WHERE a.id = b.video_id and b.state = 1 AND b.column_id = '81'\G
*************************** 1. row *************************** id: 1 select_type: SIMPLE table: b type: index_merge possible_keys: columnid_videoid,column_id,state,video_time_stamp,idx_videoid key: column_id,state key_len: 4,4 ref: NULL rows: 100 Extra: Using intersect(column_id,state); Using where *************************** 2. row *************************** id: 1 select_type: SIMPLE table: a type: eq_ref possible_keys: PRIMARY key: PRIMARY key_len: 4 ref: b.video_id rows: 1 Extra: Using where; Using index
再看下該表的索引情況:
mysql> show index from b\G
*************************** 1. row *************************** Table: b Non_unique: 0 Key_name: PRIMARY Seq_in_index: 1 Column_name: id Collation: A Cardinality: 167483 Sub_part: NULL Packed: NULL Null: Index_type: BTREE Comment: Index_comment: *************************** 2. row *************************** Table: b Non_unique: 1 Key_name: column_id Seq_in_index: 1 Column_name: column_id Collation: A Cardinality: 8374 Sub_part: NULL Packed: NULL Null: Index_type: BTREE Comment: Index_comment: *************************** 3. row *************************** Table: b Non_unique: 1 Key_name: state Seq_in_index: 2 Column_name: state Collation: A Cardinality: 5 Sub_part: NULL Packed: NULL Null: Index_type: BTREE Comment: Index_comment:
可以看到執(zhí)行計劃中,使用的是index merge,效率自然沒有用聯(lián)合索引(也有的叫做覆蓋索引)來的好了,而且 state 字段的基數(shù)(唯一性)太差,索引效果很差。刪掉兩個獨(dú)立索引,修改成聯(lián)合看看效果如何:
mysql> show index from b;
*************************** 1. row *************************** Table: b Non_unique: 0 Key_name: PRIMARY Seq_in_index: 1 Column_name: id Collation: A Cardinality: 128151 Sub_part: NULL Packed: NULL Null: Index_type: BTREE Comment: Index_comment: *************************** 2. row *************************** Table: b Non_unique: 1 Key_name: idx_columnid_state Seq_in_index: 1 Column_name: column_id Collation: A Cardinality: 3203 Sub_part: NULL Packed: NULL Null: Index_type: BTREE Comment: Index_comment: *************************** 3. row *************************** Table: b Non_unique: 1 Key_name: idx_columnid_state Seq_in_index: 2 Column_name: state Collation: A Cardinality: 3463 Sub_part: NULL Packed: NULL Null: Index_type: BTREE Comment: Index_comment: mysql> explain SELECT count(1) FROM a , b WHERE a.id = b.video_id and b.state = 1 AND b.column_id = '81' \G *************************** 1. row *************************** id: 1 select_type: SIMPLE table: b type: ref possible_keys: columnid_videoid,idx_videoid,idx_columnid_state key: columnid_videoid key_len: 4 ref: const rows: 199 Extra: Using where *************************** 2. row *************************** id: 1 select_type: SIMPLE table: a type: eq_ref possible_keys: PRIMARY key: PRIMARY key_len: 4 ref: b.video_id rows: 1 Extra: Using where; Using index
可以看到執(zhí)行計劃變成了只用到了 idx_columnid_state 索引,而且 ref 類型也變成了 const,SQL執(zhí)行耗時也從0.07s變成了0.00s,相應(yīng)的CPU負(fù)載也從336%突降到了12%不到。
總結(jié)下,從多次歷史經(jīng)驗(yàn)來看,如果CPU負(fù)載持續(xù)很高,但內(nèi)存和IO都還好的話,這種情況下,首先想到的一定是索引問題,十有八九錯不了。
相關(guān)文章
Mysql8.0壓縮包安裝方法(詳細(xì)教程一步步安裝)
這篇文章主要給大家介紹了關(guān)于Mysql8.0壓縮包安裝方法,文中介紹的非常詳細(xì),Mysql安裝的時候可以有msi安裝和zip解壓縮兩種安裝方式,文中通過圖文介紹的非常詳細(xì),需要的朋友可以參考下2023-07-07詳解MySQL?substring()?字符串截取函數(shù)
MySQL 查詢數(shù)據(jù)有時候需要對數(shù)據(jù)項(xiàng)進(jìn)行日期格式化或截取特定部分的操作,當(dāng)需要對字符串進(jìn)行截取加工時用到了 substring() 函數(shù),這篇文章主要介紹了MySQL?substring()?字符串截取函數(shù),需要的朋友可以參考下2022-07-07MySQL ORDER BY 的實(shí)現(xiàn)分析
總的來說,在 MySQL 中的ORDER BY有兩種排序?qū)崿F(xiàn)方式,一種是利用有序索引獲取有序數(shù)據(jù),另一種則是通過相應(yīng)的排序算法,將取得的數(shù)據(jù)在內(nèi)存中進(jìn)行排序2012-07-07