牛骨文教育服务平台(让学习变的简单)
博文笔记

MySQL in查询优化<一>

创建时间:2015-08-10 投稿人: 浏览次数:5346

开发说他写了个SQL特别慢,让看看。

select * from t_channel where id_ in(select distinct cdbh from sjkk_gcjl where jgsj>"2015-01-02 08:00:00" and jgsj<"2015-01-02 12:00:00");
......
30min+

然后我查询内部SQL,只需要3s+

mysql> select distinct cdbh from sjkk_gcjl where jgsj>"2015-01-02 08:00:00" and jgsj<"2015-01-02 12:00:00";
.....
1755 rows in set (3.30 sec)

mysql> select count(*) from t_channel;
....
12062 rows in set (0.70 sec)
开发写的SQL为啥那么慢呢?看看执行计划

explain extended select * from t_channel where id_ in(select distinct cdbh from sjkk_gcjl where jgsj>"2015-01-02 08:00:00" and jgsj<"2015-01-02 12:00:00");
+----+--------------------+-----------+-------+---------------+----------+---------+------+--------+----------+------------------------------+
| id | select_type        | table     | type  | possible_keys | key      | key_len | ref  | rows   | filtered | Extra                        |
+----+--------------------+-----------+-------+---------------+----------+---------+------+--------+----------+------------------------------+
|  1 | PRIMARY            | t_channel | ALL   | NULL          | NULL     | NULL    | NULL |  12062 |   100.00 | Using where                  |
|  2 | DEPENDENT SUBQUERY | sjkk_gcjl | range | idx_jgsj      | idx_jgsj | 8       | NULL | 731868 |   100.00 | Using where; Using temporary |
+----+--------------------+-----------+-------+---------------+----------+---------+------+--------+----------+------------------------------

看看数据库转换后的语句
mysql> show warnings;
SELECT
    `shanghai_full`.`t_channel`.`ID_` AS `ID_`,
    `shanghai_full`.`t_channel`.`Code_` AS `Code_`,
     ...... --这里会列出所有字段
FROM
    `shanghai_full`.`t_channel`
WHERE
    < in_optimizer > (
        `shanghai_full`.`t_channel`.`ID_` ,< EXISTS > (
            SELECT DISTINCT
                1
            FROM
                `shanghai_full`.`sjkk_gcjl`
            WHERE
                (
                    (
                        `shanghai_full`.`sjkk_gcjl`.`jgsj` > "2015-01-02 08:00:00"
                    )
                    AND (
                        `shanghai_full`.`sjkk_gcjl`.`jgsj` < "2015-01-02 12:00:00"
                    )
                    AND (
                        < CACHE > (
                            `shanghai_full`.`t_channel`.`ID_`
                        ) = `shanghai_full`.`sjkk_gcjl`.`cdbh`
                    )
                )
        )
    );

可见,经过mysql优化器后,in 给转换成exists的方式(mysql认为换成exists更快,呵呵)。

慢的原因:走了exists,查询把外表t_channel做为主表进行全表扫描,每扫描一行数据,然后对子查询进行查询看这条数据是否符合条件。

特别说明:mysql版本是5.5。在5.6中mysql做了改进,将in的这种查询转换为了join。


优化方式一(将in查询转换为连接查询)

select t1.* from t_channel t1,(select distinct cdbh from sjkk_gcjl where jgsj>"2015-01-02 08:00:00" and jgsj<"2015-01-02 12:00:00") t2 where t1.id_=t2.cdbh;
......
1264 rows in set (3.30 sec)

mysql> explain extended select t1.* from t_channel t1,(select distinct cdbh from sjkk_gcjl where jgsj>"2015-01-02 08:00:00" and jgsj<"2015-01-02 12:00:00") t2 where t1.id_=t2.cdbh;
+----+-------------+------------+--------+---------------+----------+---------+---------+--------+----------+------------------------------+
| id | select_type | table      | type   | possible_keys | key      | key_len | ref     | rows   | filtered | Extra                        |
+----+-------------+------------+--------+---------------+----------+---------+---------+--------+----------+------------------------------+
|  1 | PRIMARY     | <derived2> | ALL    | NULL          | NULL     | NULL    | NULL    |   1755 |   100.00 |                              |
|  1 | PRIMARY     | t1         | eq_ref | PRIMARY,ID_   | PRIMARY  | 74      | t2.cdbh |      1 |   100.00 | Using where                  |
|  2 | DERIVED     | sjkk_gcjl  | range  | idx_jgsj      | idx_jgsj | 8       | NULL    | 731868 |   100.00 | Using where; Using temporary |
+----+-------------+------------+--------+---------------+----------+---------+---------+--------+----------+------------------------------+

mysql> show warnings;

SELECT
    `shanghai_full`.`t1`.`ID_` AS `ID_`,
    ........ ---这里会列出所有字段FROM
    `shanghai_full`.`t_channel` `t1`
JOIN (
    SELECT DISTINCT
        `shanghai_full`.`sjkk_gcjl`.`cdbh` AS `cdbh`
    FROM
        `shanghai_full`.`sjkk_gcjl`
    WHERE
        (
            (
                `shanghai_full`.`sjkk_gcjl`.`jgsj` > "2015-01-02 08:00:00"
            )
            AND (
                `shanghai_full`.`sjkk_gcjl`.`jgsj` < "2015-01-02 12:00:00"
            )
        )
) `t2`
WHERE
    (
        `shanghai_full`.`t1`.`ID_` = `t2`.`cdbh`
    );

优化方式二(使用memory引擎的临时表)

mysql> create temporary table tmp_channel  engine=memory (select distinct cdbh from sjkk_gcjl where jgsj>"2015-01-02 08:00:00" and jgsj<"2015-01-02 12:00:00");
Query OK, 1755 rows affected (9.00 sec)
Records: 1755  Duplicates: 0  Warnings: 0
mysql> select * from t_channel where id_ in(select * from tmp_channel);
.....
1264 rows in set (0.26 sec)

mysql> explain extended select * from t_channel where id_ in(select * from tmp_channel);
+----+--------------------+-------------+------+---------------+------+---------+------+------+----------+-------------+
| id | select_type        | table       | type | possible_keys | key  | key_len | ref  | rows | filtered | Extra       |
+----+--------------------+-------------+------+---------------+------+---------+------+------+----------+-------------+
|  1 | PRIMARY            | t_channel   | ALL  | NULL          | NULL | NULL    | NULL | 3224 |   100.00 | Using where |
|  2 | DEPENDENT SUBQUERY | tmp_channel | ALL  | NULL          | NULL | NULL    | NULL |   20 |   100.00 | Using where |
+----+--------------------+-------------+------+---------------+------+---------+------+------+----------+-------------+

mysql> show warnings;
| Note  | 1003 | select `vmc_jiaqi`.`t_channel`.`ID_` AS `ID_`,`vmc_jiaqi`.`t_channel`.`Code_` AS `Code_`,`vmc_jiaqi`.`t_channel`.`HostId_` AS `HostId_`,`vmc_jiaqi`.`t_channel`.`RoadMonitorStationId_` AS `RoadMonitorStationId_`,`vmc_jiaqi`.`t_channel`.`ChannelNo_` AS `ChannelNo_`,`vmc_jiaqi`.`t_channel`.`Name_` AS `Name_`,`vmc_jiaqi`.`t_channel`.`ChannelType_` AS `ChannelType_`,`vmc_jiaqi`.`t_channel`.`Ext_` AS `Ext_`,`vmc_jiaqi`.`t_channel`.`DeviceAddress_` AS `DeviceAddress_`,`vmc_jiaqi`.`t_channel`.`MinSpeed_` AS `MinSpeed_`,`vmc_jiaqi`.`t_channel`.`MaxSpeed_` AS `MaxSpeed_`,`vmc_jiaqi`.`t_channel`.`LimitMinRatio_` AS `LimitMinRatio_`,`vmc_jiaqi`.`t_channel`.`LimitMaxRatio_` AS `LimitMaxRatio_`,`vmc_jiaqi`.`t_channel`.`Direction_` AS `Direction_`,`vmc_jiaqi`.`t_channel`.`JcDirection_` AS `JcDirection_`,`vmc_jiaqi`.`t_channel`.`LaneNum_` AS `LaneNum_`,`vmc_jiaqi`.`t_channel`.`FrameDropNum_` AS `FrameDropNum_`,`vmc_jiaqi`.`t_channel`.`RecogizeRectLeft_` AS `RecogizeRectLeft_`,`vmc_jiaqi`.`t_channel`.`RecogizeRectTop_` AS `RecogizeRectTop_`,`vmc_jiaqi`.`t_channel`.`RecogizeRectWidth_` AS `RecogizeRectWidth_`,`vmc_jiaqi`.`t_channel`.`RecogizeRectHeight_` AS `RecogizeRectHeight_`,`vmc_jiaqi`.`t_channel`.`RmpServerIp_` AS `RmpServerIp_`,`vmc_jiaqi`.`t_channel`.`RmpServerPort_` AS `RmpServerPort_`,`vmc_jiaqi`.`t_channel`.`VirtualGateServerId_` AS `VirtualGateServerId_`,`vmc_jiaqi`.`t_channel`.`LaneType_` AS `LaneType_`,`vmc_jiaqi`.`t_channel`.`DeviceType_` AS `DeviceType_`,`vmc_jiaqi`.`t_channel`.`ManufacturerId_` AS `ManufacturerId_`,`vmc_jiaqi`.`t_channel`.`IsLocalSavePicture_` AS `IsLocalSavePicture_`,`vmc_jiaqi`.`t_channel`.`OrderNO_` AS `OrderNO_`,`vmc_jiaqi`.`t_channel`.`channelStatus` AS `channelStatus` from `vmc_jiaqi`.`t_channel` where <in_optimizer>(`vmc_jiaqi`.`t_channel`.`ID_`,<exists>(select 1 from `vmc_jiaqi`.`tmp_channel` where (<cache>(`vmc_jiaqi`.`t_channel`.`ID_`) = `vmc_jiaqi`.`tmp_channel`.`cdbh`))) 
注意:第二种方式还是使用了exists的执行方式,所以这种方式没有第一种方式好,在特定的条件下可能会有用处,

















声明:该文观点仅代表作者本人,牛骨文系教育信息发布平台,牛骨文仅提供信息存储空间服务。