MySQL的子查询及相关优化学习教程

一、子查询 1、where型子查询 (把内层查询结果当作外层查询的比较条件) #不用order by 来查询最新的商品select goods_id,goods_name from goods where goods_id = (select max(goods_id) from goods); #取出每个

一、子查询 1、where型子查询(把内层查询结果当作外层查询的比较条件)

#不用order by 来查询最新的商品 select goods_id,goods_name from goods where goods_id = (select max(goods_id) from goods);

#取出每个栏目下最新的产品(goods_id唯一) select cat_id,goods_id,goods_name from goods where goods_id in(select max(goods_id) from goods group by cat_id);

2、from型子查询(把内层的查询结果供外层再次查询) #用子查询查出挂科两门及以上的同学的平均成绩 思路:

#先查出哪些同学挂科两门以上 select name,count() as gk from stu where score < 60 having gk >=2; #以上查询结果,我们只要名字就可以了,所以再取一次名字 select name from (select name,count() as gk from stu having gk >=2) as t; #找出这些同学了,那么再计算他们的平均分 select name,avg(score) from stu where name in (select name from (select name,count(*) as gk from stu having gk >=2) as t) group by name;

3、exists型子查询(把外层查询结果拿到内层,看内层的查询是否成立)

#查询哪些栏目下有商品,栏目表category,商品表goods select cat_id,cat_name from category where exists(select * from goods where goods.cat_id = category.cat_id);

二、优化从句式的形式看,子查询分为特殊格式子查询和非特殊格式子查询,特殊格式的子查询中又包括IN、ALL、ANY、SOME、EXISTS等类型的子查询,对于有的类型的子查询,MySQL有的支持优化,有的不支持,具体情况如下。

 

示例一,MySQL不支持对EXISTS类型的子查询的优化:

EXISTS类型的相关子查询,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE EXISTS (SELECT 1 FROM t2 WHERE t1.a1= t2.a2 AND t2.a2>10);

+----+--------------------+-------+------+------+-------------+ | id | select_type | table | type | key | Extra |

+----+--------------------+-------+------+------+-------------+

| 1 | PRIMARY | t1 | ALL | NULL | Using where |

| 2 | DEPENDENT SUBQUERY | t2 | ALL | NULL | Using where |

+----+--------------------+-------+------+------+-------------+

2 rows in set, 2 warnings (0.00 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1

where exists(/ select#2 /

select 1

from test.t2

where ((test.t1.a1 = test.t2.a2) and (test.t2.a2 > 10))

)

从查询执行计划看,子查询存在,MySQL没有进一步做子查询的优化工作。

另外的一个EXISTS类型的相关子查询,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE EXISTS (SELECT 1 FROM t2 WHERE t1.b1= t2.b2 AND t1.a1=10);

+----+--------------------+-------+------+------+-------------+

| id | select_type | table | type | key | Extra |

+----+--------------------+-------+------+------+-------------+

| 1 | PRIMARY | t1 | ALL | NULL | Using where |

| 2 | DEPENDENT SUBQUERY | t2 | ALL | NULL | Using where |

+----+--------------------+-------+------+------+-------------+

2 rows in set, 3 warnings (0.02 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1

where exists(/ select#2 /

select 1

from test.t2

where ((test.t1.b1 = test.t2.b2) and (test.t1.a1 = 10))

)

从查询执行计划看,子查询存在,MySQL没有进一步做子查询的优化工作。

 

示例二,MySQL不支持对NOT EXISTS类型的子查询的优化:

NOT EXISTS类型的相关子查询,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE NOT EXISTS (SELECT 1 FROM t2 WHERE t1.a1= t2.a2 AND t2.a2>10);

+----+--------------------+-------+------+------+-------------+

| id | select_type | table | type | key | Extra |

+----+--------------------+-------+------+------+-------------+

| 1 | PRIMARY | t1 | ALL | NULL | Using where |

| 2 | DEPENDENT SUBQUERY | t2 | ALL | NULL | Using where |

+----+--------------------+-------+------+------+-------------+

2 rows in set, 2 warnings (0.00 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1

where (not(exists(

/ select#2 / select 1

from test.t2

where ((test.t1.a1 = test.t2.a2) and (test.t2.a2 > 10))))

)

从查询执行计划看,子查询存在,MySQL没有进一步做子查询的优化工作。

 

另外的一个NOT EXISTS类型的相关子查询,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE NOT EXISTS (SELECT 1 FROM t2 WHERE t1.b1= t2.b2 AND t1.a1=10);

+----+--------------------+-------+------+------+-------------+

| id | select_type | table | type | key | Extra |

+----+--------------------+-------+------+------+-------------+

| 1 | PRIMARY | t1 | ALL | NULL | Using where |

| 2 | DEPENDENT SUBQUERY | t2 | ALL | NULL | Using where |

+----+--------------------+-------+------+------+-------------+

2 rows in set, 3 warnings (0.00 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1

where (not(exists(

/ select#2 / select 1

from test.t2

where ((test.t1.b1 = test.t2.b2) and (test.t1.a1 = 10))))

)

从查询执行计划看,子查询存在,MySQL没有进一步做子查询的优化工作。

 

示例三,MySQL支持对IN类型的子查询的优化,按也有不支持的情况存在:

IN非相关子查询,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1 IN (SELECT a2 FROM t2 WHERE t2.a2>10);

+----+--------------+-------------+------+------+----------------------------------------------------+

| id | select_type | table | type | key | Extra |

+----+--------------+-------------+------+------+----------------------------------------------------+

| 1 | SIMPLE | | ALL | NULL | NULL |

| 1 | SIMPLE | t1 | ALL | NULL | Using where; Using join buffer (Block Nested Loop) |

| 2 | MATERIALIZED | t2 | ALL | NULL | Using where |

+----+--------------+-------------+------+------+----------------------------------------------------+

3 rows in set, 1 warning (0.00 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1 semi join (test.t2)

where ((test.t1.a1 = &lt;subquery2&gt;.a2) and (test.t2.a2 > 10))

从查询执行计划看,表t2被物化后,与表t1执行了半连接(semi join)。尽管有“subquery2”这样的内容看起来是子查询,但是表t2已经被上拉到表t1层执行了半连接,所以MySQL支持IN子查询优化为半连接操作。

 

另外一个IN非相关子查询,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1 IN (SELECT a2 FROM t2 WHERE t2.a2=10);

+----+--------------+-------------+------+------+----------------------------------------------------+

| id | select_type | table | type | key | Extra |

+----+--------------+-------------+------+------+----------------------------------------------------+

| 1 | SIMPLE | | ALL | NULL | Using where |

| 1 | SIMPLE | t1 | ALL | NULL | Using where; Using join buffer (Block Nested Loop) |

| 2 | MATERIALIZED | t2 | ALL | NULL | Using where |

+----+--------------+-------------+------+------+----------------------------------------------------+

3 rows in set, 1 warning (0.02 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1 semi join (test.t2)

where ((&lt;subquery2&gt;.a2 = 10) and (test.t1.a1 = 10) and (test.t2.a2 = 10))

从查询执行计划看,子查询不存在,表t1和t2直接做了块嵌套循环半连接(Block Nested Loop),把子查询上拉到父查询中用嵌套循环半连接完成IN操作。另外,由于子查询上拉,使得增加连接条件“a1=a2”,而原先的条件“a2=10”可以利用常量传递优化技术,使得“a1=a2=10”,所以查询执行计划中,两个索引扫描的条件分别为:a1 = 10、a2 = 10。

 

另外一个IN非相关子查询,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1 IN (SELECT a2 FROM t2 WHERE t1.a1=10);

+----+-------------+-------+------+------------------------------------------------------------------+

| id | select_type | table | type | Extra |

+----+-------------+-------+------+------------------------------------------------------------------+

| 1 | SIMPLE | t2 | ALL | Using where; Start temporary |

| 1 | SIMPLE | t1 | ALL | Using where; End temporary; Using join buffer (Block Nested Loop)|

+----+-------------+-------+------+------------------------------------------------------------------+

2 rows in set, 2 warnings (0.00 sec)

被查询优化器处理后的语句为: / select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1 semi join (test.t2)

where ((test.t2.a2 = 10) and (test.t1.a1 = 10))

从查询执行计划看,子子查询不存在,表t1和t2直接做了块嵌套循环连接(Block Nested Loop),但属于半连接操作(semi join),把子查询上拉到父查询中用嵌套循环半连接完成IN操作。

 

示例四,MySQL支持对NOT IN类型的子查询的优化

NOT IN非相关子查询,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1 NOT IN (SELECT a2 FROM t2 WHERE t2.a2>10);

+----+-------------+-------+------+------+-------------+

| id | select_type | table | type | key | Extra |

+----+-------------+-------+------+------+-------------+

| 1 | PRIMARY | t1 | ALL | NULL | Using where |

| 2 | SUBQUERY | t2 | ALL | NULL | Using where |

+----+-------------+-------+------+------+-------------+

2 rows in set, 1 warning (0.02 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1

where (not((

test.t1.a1,test.t1.a1 in (

&lt;materialize&gt; (/* select#2 */

  select `test`.`t2`.`a2`

  from `test`.`t2`

  where (`test`.`t2`.`a2` &gt; 10)

  having 1

),

&lt;primary_index_lookup&gt;(

  `test`.`t1`.`a1` in &lt;temporary table&gt; on &lt;auto_key&gt;

  where ((`test`.`t1`.`a1` = `materialized-subquery`.`a2`))

)

)

))

)

从查询执行计划看,表t2做了子查询(SUBQUERY)。而子查询被物化(materialize)。所以,MySQL对于NOT IN子查询采用了物化的优化方式,但不支持子查询的消除。

 

另外一个NOT IN非相关子查询,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1 NOT IN (SELECT a2 FROM t2 WHERE t2.a2=10);

+----+-------------+-------+------+------+-------------+

| id | select_type | table | type | key | Extra |

+----+-------------+-------+------+------+-------------+

| 1 | PRIMARY | t1 | ALL | NULL | Using where |

| 2 | SUBQUERY | t2 | ALL | NULL | Using where |

+----+-------------+-------+------+------+-------------+

2 rows in set, 1 warning (0.00 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,test.t1.b1 AS b1

from test.t1

where (not((

test.t1.a1,test.t1.a1 in (

&lt;materialize&gt; (/* select#2 */

  select `test`.`t2`.`a2`

  from `test`.`t2`

  where (`test`.`t2`.`a2` = 10)

  having 1

),

&lt;primary_index_lookup&gt;(

  `test`.`t1`.`a1` in &lt;temporary table&gt; on &lt;auto_key&gt;

  where ((`test`.`t1`.`a1` = `materialized-subquery`.`a2`))

)

)

))

)

从查询执行计划看,表t2做了子查询(SUBQUERY)。而子查询被物化(materialize)。所以,MySQL对于NOT IN子查询采用了物化的优化方式,但不支持子查询的消除。

 

示例五,MySQL支持对ALL类型的子查询的优化:

不相关的ALL子查询,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1 >ALL (SELECT a2 FROM t2 WHERE t2.a2>10);

+----+-------------+-------+------+------+-------------+

| id | select_type | table | type | key | Extra |

+----+-------------+-------+------+------+-------------+

| 1 | PRIMARY | t1 | ALL | NULL | Using where |

| 2 | SUBQUERY | t2 | ALL | NULL | Using where |

+----+-------------+-------+------+------+-------------+

2 rows in set, 1 warning (0.00 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,test.t1.b1 AS b1

from test.t1

where ((test.t1.a1 <= (

/ select#2 /

select test.t2.a2

from test.t2

where (test.t2.a2 > 10)

)

))

从查询执行计划看,出现了子查询(SUBQUERY),但是,子查询被“<= ”操作符限制,而子查询中的被查询列a2上存在唯一索引,所以可以利用索引求最值,所以MySQL支持“>ALL”式的子查询优化,子查询只被执行一次即可求得最大值。

 

不相关的ALL子查询,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1 =ALL (SELECT a2 FROM t2 WHERE t2.a2=10);

+----+--------------------+-------+------+------+-------------+

| id | select_type | table | type | key | Extra |

+----+--------------------+-------+------+------+-------------+

| 1 | PRIMARY | t1 | ALL | NULL | Using where |

| 2 | DEPENDENT SUBQUERY | t2 | ALL | NULL | Using where |

+----+--------------------+-------+------+------+-------------+

2 rows in set, 1 warning (0.00 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,test.t1.b1 AS b1

from test.t1

where ((

test.t1.a1,(

/* select#2 */ select 1 from `test`.`t2`

where ((`test`.`t2`.`a2` = 10) and

  &lt;if&gt;(outer_field_is_not_null,

    ((&lt;cache&gt;(`test`.`t1`.`a1`) &lt;&gt; 10) or &lt;cache&gt;(isnull(10))),

    true

  )

)

having &lt;if&gt;(outer_field_is_not_null, &lt;is_not_null_test&gt;(`test`.`t2`.`a2`), true)

)

))

从查询执行计划看,出现了子查询(SUBQUERY),但是被查询优化器处理后的语句中包含“exists”,这表明MySQL对于“=ALL”式的子查询优化用“EXISTS strategy”方式优化,所以MySQL支持“=ALL”式的子查询优化。

 

不相关的ALL子查询,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1

+----+-------------+-------+------+------+-------------+

| id | select_type | table | type | key | Extra |

+----+-------------+-------+------+------+-------------+

| 1 | PRIMARY | t1 | ALL | NULL | Using where |

| 2 | SUBQUERY | t2 | ALL | NULL | Using where |

+----+-------------+-------+------+------+-------------+

2 rows in set, 1 warning (0.00 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,test.t1.b1 AS b1

from test.t1

where ((test.t1.a1 >=

(/ select#2 /

select `test`.`t2`.`a2`

from `test`.`t2`

where (`test`.`t2`.`a2` = 10)

)

))

从查询执行计划看,出现了子查询(SUBQUERY),但是,子查询被“>= ”操作符限制,而子查询中的被查询列a2上存在唯一索引,所以可以利用索引求最值,所以MySQL支持“

 

示例六,MySQL支持对SOME类型的子查询的优化:

使用了“>SOME”式子的子查询被优化,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1 >SOME (SELECT a2 FROM t2 WHERE t2.a2>10);

+----+-------------+-------+------+------+-------------+

| id | select_type | table | type | key | Extra |

+----+-------------+-------+------+------+-------------+

| 1 | PRIMARY | t1 | ALL | NULL | Using where |

| 2 | SUBQUERY | t2 | ALL | NULL | Using where |

+----+-------------+-------+------+------+-------------+

2 rows in set, 1 warning (0.05 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1

where ((test.t1.a1 > (

/ select#2 /

select min(test.t2.a2)

from test.t2

where (test.t2.a2 > 10)

)))

从查询执行计划看,出现了子查询(SUBQUERY),但是,子查询被“min”函数限制,而子查询中的被查询列a2上存在唯一索引,所以可以利用索引求最值,所以MySQL支持“>SOME”式的子查询优化,子查询只被执行一次即可求得最大值。

 

使用了“=SOME”式子的子查询被优化,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1 =SOME (SELECT a2 FROM t2 WHERE t2.a2=10);

+----+--------------+-------------+------+------+----------------------------------------------------+

| id | select_type | table | type | key | Extra |

+----+--------------+-------------+------+------+----------------------------------------------------+

| 1 | SIMPLE | | ALL | NULL | Using where |

| 1 | SIMPLE | t1 | ALL | NULL | Using where; Using join buffer (Block Nested Loop) |

| 2 | MATERIALIZED | t2 | ALL | NULL | Using where |

+----+--------------+-------------+------+------+----------------------------------------------------+

3 rows in set, 1 warning (0.01 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1 semi join (test.t2)

where ((&lt;subquery2&gt;.a2 = 10) and (test.t1.a1 = 10) and (test.t2.a2 = 10))

从查询执行计划看,没有出现了子查询,表t2被物化,与表t1进行了半连接。

 

使用了“

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1

+----+-------------+-------+------+------+-------------+

| id | select_type | table | type | key | Extra |

+----+-------------+-------+------+------+-------------+

| 1 | PRIMARY | t1 | ALL | NULL | Using where |

| 2 | SUBQUERY | t2 | ALL | NULL | Using where |

+----+-------------+-------+------+------+-------------+

2 rows in set, 1 warning (0.00 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1

where (

(

`test`.`t1`.`a1` &lt; (/* select#2 */

  select max(`test`.`t2`.`a2`)

  from `test`.`t2`

  where (`test`.`t2`.`a2` = 10)

)

)

)

从查询执行计划看,出现了子查询(SUBQUERY),但是,子查询被“max”函数限制,而子查询中的被查询列a2上存在唯一索引,所以可以利用索引求最值,所以MySQL支持“

 

示例七,MySQL支持对ANY类型的子查询的优化:

使用了“>ANY”式子的子查询被优化,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1 >ANY (SELECT a2 FROM t2 WHERE t2.a2>10);

+----+-------------+-------+------+------+-------------+

| id | select_type | table | type | key | Extra |

+----+-------------+-------+------+------+-------------+

| 1 | PRIMARY | t1 | ALL | NULL | Using where |

| 2 | SUBQUERY | t2 | ALL | NULL | Using where |

+----+-------------+-------+------+------+-------------+

2 rows in set, 1 warning (0.00 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1

where (

(

`test`.`t1`.`a1` &gt; (/* select#2 */

  select min(`test`.`t2`.`a2`)

  from `test`.`t2`

  where (`test`.`t2`.`a2` &gt; 10)

)

)

)

从查询执行计划看,出现了子查询(SUBQUERY),但是,子查询被“min”函数限制,而子查询中的被查询列a2上存在唯一索引,所以可以利用索引求最值,所以MySQL支持“>ANY”式的子查询优化,子查询只被执行一次即可求得最小值。

 

使用了“=ANY”式子的子查询被优化,查询执行计划如下:

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1 =ANY (SELECT a2 FROM t2 WHERE t2.a2>10);

+----+--------------+-------------+------+------+----------------------------------------------------+

| id | select_type | table | type | key | Extra |

+----+--------------+-------------+------+------+----------------------------------------------------+

| 1 | SIMPLE | | ALL | NULL | NULL |

| 1 | SIMPLE | t1 | ALL | NULL | Using where; Using join buffer (Block Nested Loop) |

| 2 | MATERIALIZED | t2 | ALL | NULL | Using where |

+----+--------------+-------------+------+------+----------------------------------------------------+

3 rows in set, 1 warning (0.02 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1 semi join (test.t2)

where ((test.t1.a1 = &lt;subquery2&gt;.a2) and (test.t2.a2 > 10))

从查询执行计划看,没有出现了子查询,表t2被物化,与表t1进行了半连接。

 

使用了“

mysql> EXPLAIN EXTENDED SELECT * FROM t1 WHERE t1.a1 10);

+----+-------------+-------+------+------+-------------+

| id | select_type | table | type | key | Extra |

+----+-------------+-------+------+------+-------------+

| 1 | PRIMARY | t1 | ALL | NULL | Using where |

| 2 | SUBQUERY | t2 | ALL | NULL | Using where |

+----+-------------+-------+------+------+-------------+

2 rows in set, 1 warning (0.00 sec)

被查询优化器处理后的语句为:

/ select#1 / select test.t1.id1 AS id1,test.t1.a1 AS a1,

test.t1.b1 AS b1

from test.t1

where (

(

`test`.`t1`.`a1` &lt; (/* select#2 */

  select max(`test`.`t2`.`a2`)

  from `test`.`t2`

  where (`test`.`t2`.`a2` &gt; 10)

)

)

)

从查询执行计划看,出现了子查询(SUBQUERY),但是,子查询被“max”函数限制,而子查询中的被查询列a2上存在唯一索引,所以可以利用索引求最值,所以MySQL支持“