mysql in語(yǔ)句子查詢效率慢的優(yōu)化技巧示例
表結(jié)構(gòu)如下,文章只有690篇。
文章表article(id,title,content) 標(biāo)簽表tag(tid,tag_name) 標(biāo)簽文章中間表article_tag(id,tag_id,article_id)
其中有個(gè)標(biāo)簽的tid是135,查詢標(biāo)簽tid是135的文章列表。
690篇文章,用以下的語(yǔ)句查詢,奇慢:
select id,title from article where id in( select article_id from article_tag where tag_id=135 )
其中這條速度很快:
select article_id from article_tag where tag_id=135
查詢結(jié)果是五篇文章,id為428,429,430,431,432
用下面sql來(lái)查文章也很快:
select id,title from article where id in( 428,429,430,431,432 )
解決方法:
select id,title from article where id in( select article_id from (select article_id from article_tag where tag_id=135) as tbt )
其它解決方法:(舉例)
mysql> select * from abc_number_prop where number_id in (select number_id from abc_number_phone where phone = '82306839');
為了節(jié)省篇幅,省略了輸出內(nèi)容,下同。
67 rows in set (12.00 sec)
只有67行數(shù)據(jù)返回,卻花了12秒,而系統(tǒng)中可能同時(shí)會(huì)有很多這樣的查詢,系統(tǒng)肯定扛不住。用desc看一下(注:explain也可)
mysql> desc select * from abc_number_prop where number_id in (select number_id from abc_number_phone where phone = '82306839'); +----+--------------------+------------------+--------+-----------------+-------+---------+------------+---------+--------------------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+--------------------+------------------+--------+-----------------+-------+---------+------------+---------+--------------------------+ | 1 | PRIMARY | abc_number_prop | ALL | NULL | NULL | NULL | NULL | 2679838 | Using where | | 2 | DEPENDENT SUBQUERY | abc_number_phone | eq_ref | phone,number_id | phone | 70 | const,func | 1 | Using where; Using index | +----+--------------------+------------------+--------+-----------------+-------+---------+------------+---------+--------------------------+ 2 rows in set (0.00 sec)
可以看出,在執(zhí)行此查詢時(shí)會(huì)掃描兩百多萬(wàn)行,難道是沒有創(chuàng)建索引嗎,看一下
mysql>show index from abc_number_phone; +------------------+------------+-------------+--------------+-----------------+-----------+-------------+----------+--------+------+------------+---------+---------------+ | Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment | Index_comment | +------------------+------------+-------------+--------------+-----------------+-----------+-------------+----------+--------+------+------------+---------+---------------+ | abc_number_phone | 0 | PRIMARY | 1 | number_phone_id | A | 36879 | NULL | NULL | | BTREE | | | | abc_number_phone | 0 | phone | 1 | phone | A | 36879 | NULL | NULL | | BTREE | | | | abc_number_phone | 0 | phone | 2 | number_id | A | 36879 | NULL | NULL | | BTREE | | | | abc_number_phone | 1 | number_id | 1 | number_id | A | 36879 | NULL | NULL | | BTREE | | | | abc_number_phone | 1 | created_by | 1 | created_by | A | 36879 | NULL | NULL | | BTREE | | | | abc_number_phone | 1 | modified_by | 1 | modified_by | A | 36879 | NULL | NULL | YES | BTREE | | | +------------------+------------+-------------+--------------+-----------------+-----------+-------------+----------+--------+------+------------+---------+---------------+ 6 rows in set (0.06 sec) mysql>show index from abc_number_prop; +-----------------+------------+-------------+--------------+----------------+-----------+-------------+----------+--------+------+------------+---------+---------------+ | Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment | Index_comment | +-----------------+------------+-------------+--------------+----------------+-----------+-------------+----------+--------+------+------------+---------+---------------+ | abc_number_prop | 0 | PRIMARY | 1 | number_prop_id | A | 311268 | NULL | NULL | | BTREE | | | | abc_number_prop | 1 | number_id | 1 | number_id | A | 311268 | NULL | NULL | | BTREE | | | | abc_number_prop | 1 | created_by | 1 | created_by | A | 311268 | NULL | NULL | | BTREE | | | | abc_number_prop | 1 | modified_by | 1 | modified_by | A | 311268 | NULL | NULL | YES | BTREE | | | +-----------------+------------+-------------+--------------+----------------+-----------+-------------+----------+--------+------+------------+---------+---------------+ 4 rows in set (0.15 sec)
從上面的輸出可以看出,這兩張表在number_id字段上創(chuàng)建了索引的。
看看子查詢本身有沒有問(wèn)題。
mysql> desc select number_id from abc_number_phone where phone = '82306839'; +----+-------------+------------------+------+---------------+-------+---------+-------+------+--------------------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+-------------+------------------+------+---------------+-------+---------+-------+------+--------------------------+ | 1 | SIMPLE | abc_number_phone | ref | phone | phone | 66 | const | 6 | Using where; Using index | +----+-------------+------------------+------+---------------+-------+---------+-------+------+--------------------------+ 1 row in set (0.00 sec)
沒有問(wèn)題,只需要掃描幾行數(shù)據(jù),索引起作用了。
查詢出來(lái)看看:
mysql> select number_id from abc_number_phone where phone = '82306839'; +-----------+ | number_id | +-----------+ | 8585 | | 10720 | | 148644 | | 151307 | | 170691 | | 221897 | +-----------+ 6 rows in set (0.00 sec)
直接把子查詢得到的數(shù)據(jù)放到上面的查詢中
mysql> select * from abc_number_prop where number_id in (8585, 10720, 148644, 151307, 170691, 221897); 67 rows in set (0.03 sec)
速度也快,看來(lái)MySQL在處理子查詢的時(shí)候是不夠好。我在MySQL 5.1.42 和 MySQL 5.5.19 都進(jìn)行了嘗試,都有這個(gè)問(wèn)題。
搜索了一下網(wǎng)絡(luò),發(fā)現(xiàn)很多人都遇到過(guò)這個(gè)問(wèn)題:
參考資料1:MySQL優(yōu)化之使用連接(join)代替子查詢
參考資料2:MYSQL子查詢和嵌套查詢優(yōu)化實(shí)例解析
根據(jù)網(wǎng)上這些資料的建議,改用join來(lái)試試。
修改前:
select * from abc_number_prop where number_id in (select number_id from abc_number_phone where phone = '82306839');
修改后:
select a.* from abc_number_prop a inner join abc_number_phone b on a.number_id = b.number_id where phone = '82306839'; mysql> select a.* from abc_number_prop a inner join abc_number_phone b on a.number_id = b.number_id where phone = '82306839'; 67 rows in set (0.00 sec)
效果不錯(cuò),查詢所用時(shí)間幾乎為0??匆幌翸ySQL是怎么執(zhí)行這個(gè)查詢的
mysql>desc select a.* from abc_number_prop a inner join abc_number_phone b on a.number_id = b.number_id where phone = '82306839'; +----+-------------+-------+------+-----------------+-----------+---------+-----------------+------+--------------------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+-------------+-------+------+-----------------+-----------+---------+-----------------+------+--------------------------+ | 1 | SIMPLE | b | ref | phone,number_id | phone | 66 | const | 6 | Using where; Using index | | 1 | SIMPLE | a | ref | number_id | number_id | 4 | eap.b.number_id | 3 | | +----+-------------+-------+------+-----------------+-----------+---------+-----------------+------+--------------------------+ 2 rows in set (0.00 sec)
小結(jié):當(dāng)子查詢速度慢時(shí),可用JOIN來(lái)改寫一下該查詢來(lái)進(jìn)行優(yōu)化。
網(wǎng)上也有文章說(shuō),使用JOIN語(yǔ)句的查詢不一定總比使用子查詢的語(yǔ)句快。
mysql手冊(cè)也提到過(guò),具體的原文在mysql文檔的這個(gè)章節(jié):
I.3. Restrictions on Subqueries
13.2.8. Subquery Syntax
摘抄:
1)關(guān)于使用IN的子查詢:
Subquery optimization for IN is not as effective as for the = operator or for IN(value_list) constructs.
A typical case for poor IN subquery performance is when the subquery returns a small number of rows but the outer query returns a large number of rows to be compared to the subquery result.
The problem is that, for a statement that uses an IN subquery, the optimizer rewrites it as a correlated subquery. Consider the following statement that uses an uncorrelated subquery:
SELECT ... FROM t1 WHERE t1.a IN (SELECT b FROM t2);
The optimizer rewrites the statement to a correlated subquery:
SELECT ... FROM t1 WHERE EXISTS (SELECT 1 FROM t2 WHERE t2.b = t1.a);
If the inner and outer queries return M and N rows, respectively, the execution time becomes on the order of O(M×N), rather than O(M+N) as it would be for an uncorrelated subquery.
An implication is that an IN subquery can be much slower than a query written using an IN(value_list) construct that lists the same values that the subquery would return.
2)關(guān)于把子查詢轉(zhuǎn)換成join的:
The optimizer is more mature for joins than for subqueries, so in many cases a statement that uses a subquery can be executed more efficiently if you rewrite it as a join.
An exception occurs for the case where an IN subquery can be rewritten as a SELECT DISTINCT join. Example:
SELECT col FROM t1 WHERE id_col IN (SELECT id_col2 FROM t2 WHERE condition);
That statement can be rewritten as follows:
SELECT DISTINCT col FROM t1, t2 WHERE t1.id_col = t2.id_col AND condition;
But in this case, the join requires an extra DISTINCT operation and is not more efficient than the subquery
總結(jié)
以上就是本文關(guān)于mysql in語(yǔ)句子查詢效率慢的優(yōu)化技巧示例的全部?jī)?nèi)容,感興趣的朋友而可以參閱:淺談mysql的子查詢聯(lián)合與in的效率、企業(yè)生產(chǎn)MySQL優(yōu)化介紹等,有什么問(wèn)題可以留言,歡迎大家一起交流參考。
希望本文所述對(duì)大家有所幫助。
相關(guān)文章
mysql使用mysqld_multi部署單機(jī)多實(shí)例的方法教程
這篇文章主要給大家介紹了關(guān)于mysql使用mysqld_multi部署單機(jī)多實(shí)例的相關(guān)資料,文中通過(guò)示例代碼將實(shí)現(xiàn)的步驟一步步介紹的非常詳細(xì),對(duì)大家的學(xué)習(xí)或者工作具有一定的參考學(xué)習(xí)價(jià)值,需要的朋友們下面隨著小編來(lái)一起學(xué)習(xí)學(xué)習(xí)吧。2018-03-03MySql比較運(yùn)算符正則式匹配REGEXP的詳細(xì)使用詳解
這篇文章主要介紹了MySql比較運(yùn)算符正則式匹配REGEXP的詳細(xì)使用詳解,文中通過(guò)示例代碼介紹的非常詳細(xì),對(duì)大家的學(xué)習(xí)或者工作具有一定的參考學(xué)習(xí)價(jià)值,需要的朋友們下面隨著小編來(lái)一起學(xué)習(xí)學(xué)習(xí)吧2020-10-10Windows10系統(tǒng)下MySQL(8.0.37)安裝與配置教程
相信很多人都遇到過(guò)安裝Mysql的時(shí)候出現(xiàn)各種各樣的問(wèn)題,下面這篇文章主要給大家介紹了關(guān)于Windows10系統(tǒng)下MySQL(8.0.37)安裝與配置的相關(guān)資料,文中通過(guò)圖文介紹的非常詳細(xì),需要的朋友可以參考下2024-07-07MySQL order by與group by查詢優(yōu)化實(shí)現(xiàn)詳解
order by 子句盡量使用index方式排序(即using index),避免使用filesort方式排序(即using filesort)。Index方式效率高,它指MySQL掃描索引本身完成排序,filesort則效率低2022-11-11mysql存儲(chǔ)過(guò)程?返回?list結(jié)果集方式
這篇文章主要介紹了mysql存儲(chǔ)過(guò)程?返回?list結(jié)果集方式,具有很好的參考價(jià)值,希望對(duì)大家有所幫助。如有錯(cuò)誤或未考慮完全的地方,望不吝賜教2022-09-09MySQL使用distinct去掉查詢結(jié)果重復(fù)的問(wèn)題
這篇文章主要介紹了MySQL使用distinct去掉查詢結(jié)果重復(fù)的問(wèn)題,具有很好的參考價(jià)值,希望對(duì)大家有所幫助,如有錯(cuò)誤或未考慮完全的地方,望不吝賜教2024-01-01MySQL定時(shí)任務(wù)(EVENT事件)如何配置詳解
這篇文章主要介紹了MySQL定時(shí)任務(wù)(EVENT事件)如何配置詳解,文中通過(guò)示例代碼介紹的非常詳細(xì),對(duì)大家的學(xué)習(xí)或者工作具有一定的參考學(xué)習(xí)價(jià)值,需要的朋友們下面隨著小編來(lái)一起學(xué)習(xí)學(xué)習(xí)吧2021-02-02MySQL之高可用集群部署及故障切換實(shí)現(xiàn)
這篇文章主要介紹了MySQL之高可用集群部署及故障切換實(shí)現(xiàn),文中通過(guò)示例代碼介紹的非常詳細(xì),對(duì)大家的學(xué)習(xí)或者工作具有一定的參考學(xué)習(xí)價(jià)值,需要的朋友們下面隨著小編來(lái)一起學(xué)習(xí)學(xué)習(xí)吧2021-04-04