Author: 令猴
通过CREATE TEMPORARY TABLE 创建的临时表,这种临时表称为外部临时表。这种临时表只对当前用户可见,当前会话结束的时候,该临时表会自动关闭。这种临时表的命名与非临时表可以同名(同名后非临时表将对当前会话不可见,直到临时表被删除)。
内部临时表是一种特殊轻量级的临时表,用来进行性能优化。这种临时表会被MySQL自动创建并用来存储某些操作的中间结果。这些操作可能包括在优化阶段或者执行阶段。这种内部表对用户来说是不可见的,但是通过EXPLAIN或者SHOW STATUS可以查看MYSQL是否使用了内部临时表用来帮助完成某个操作。内部临时表在SQL语句的优化过程中扮演着非常重要的角色, MySQL中的很多操作都要依赖于内部临时表来进行优化。但是使用内部临时表需要创建表以及中间数据的存取代价,所以用户在写SQL语句的时候应该尽量的去避免使用临时表。
内部临时表有两种类型:一种是HEAP临时表,这种临时表的所有数据都会存在内存中,对于这种表的操作不需要IO操作。另一种是OnDisk临时表,顾名思义,这种临时表会将数据存储在磁盘上。OnDisk临时表用来处理中间结果比较大的操作。如果HEAP临时表存储的数据大于MAX_HEAP_TABLE_SIZE(详情请参考MySQL手册中系统变量部分),HEAP临时表将会被自动转换成OnDisk临时表。OnDisk临时表在5.7中可以通过INTERNAL_TMP_DISK_STORAGE_ENGINE系统变量选择使用MyISAM引擎或者InnoDB引擎。
本篇文章主要介绍哪些操作可能会利用到内部临时表。如果用户在书写SQL语句的时候能够尽量少的使用内部临时表进行查询优化,将有效的提高查询执行的效率。
首先我们定义一个表t1,
CREATE TABLE t1(
a int,
b int);
INSERT INTO t1 VALUES(1,2),(3,4);
下面所有的操作都是基于表t1进行举例的。
SQL_BUFFER_RESULT主要用来让MySQL尽早的释放表上的锁。因为如果数据量很大的话,需要较长时间将数据发送到客户端,通过将数据缓冲到临时表中可以有效的减少读锁对表的占用时间。 例如:
mysql> explain format=json select SQL_BUFFER_RESULT * from t1;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "2.00"
},
"buffer_result": {
"using_temporary_table": true,
"table": {
"table_name": "t1",
"access_type": "ALL",
...
在5.7中,由于采用了新的优化方式,我们需要使用 set optimizer_switch=’derived_merge=off’来禁止derived table合并到外层的Query中。 例如:
mysql> explain format=json select * from (select * from t1) as tt;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "2.40"
},
"table": {
"table_name": "tt",
"access_type": "ALL",
...
"materialized_from_subquery": {
"using_temporary_table": true,
...
我们当前不能使用EXPLAIN来查看是否读取系统表数据需要利用到内部临时表,但是可以通过SHOW STATUS来查看是否利用到了内部临时表。 例如:
mysql> select * from information_schema.character_sets;
mysql> show status like 'CREATE%';
mysql> explain format=json select distinct a from t1;
EXPLAIN
{
{
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "1.60"
},
"duplicates_removal": {
"using_temporary_table": true,
...
1)如果连接表使用BNL(Batched Nestloop)/BKA(Batched Key Access) 例如:
1))BNL默认是打开的
mysql> explain format=json select * from t1, t1 as t2 order by t1.a;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "22.00"
},
"ordering_operation": {
"using_temporary_table": true,
...
2))关掉BNL后,ORDER BY将直接使用filesort。
mysql> set optimizer_switch='block_nested_loop=off';
Query OK, 0 rows affected (0.00 sec)
mysql> explain format=json select * from t1, t1 as t2 order by t1.a;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "25.00"
},
"ordering_operation": {
"using_filesort": true,
...
2)ORDER BY的列不属于执行计划中第一个连接表的列。 例如:
mysql> explain format=json select * from t as t1, t as t2 order by t2.a;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "25.00"
},
"ordering_operation": {
"using_temporary_table": true,
...
3)如果ORDER BY的表达式是个复杂表达式。
那么什么样的ORDER BY表达式,MySQL认为是复杂表达式呢?
1))如果排序表达式是SP或者UDF。 例如:
drop function if exists func1;
delimiter |
create function func1(x int)
returns int deterministic
begin
declare z1, z2 int;
set z1 = x;
set z2 = z1+2;
return z2;
end|
delimiter ;
explain format=json select * from t1 order by func1(a);
{
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "2.20"
},
"ordering_operation": {
"using_temporary_table": true,
...
2))ORDER BY的列包含聚集函数
为了简化执行计划,我们利用INDEX来优化GROUP BY语句。 例如:
create index idx1 on t1(a);
explain format=json SELECt a FROM t1 group by a order by sum(a);
| {
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "1.20"
},
"ordering_operation": {
"using_temporary_table": true,
"using_filesort": true,
"grouping_operation": {
"using_filesort": false,
...
drop index idx1 on t1;
3))ORDER BY的列中包含有SCALAR SUBQUERY,当然该SCALAR SUBQUERY没有被优化掉。 例如:
explain format=json select (select rand() from t1 limit 1) as a from t1 order by a;
| {
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "1.20"
},
"ordering_operation": {
"using_temporary_table": true,
"using_filesort": true,
...
4) 如果查询既带有ORDER BY同时也有GROUP BY语句,但是两个语句使用的列不相同。
注意: 如果是5.7,我们需要将sql_mode设置为非only_full_group_by模式,否则会报错。
同样为了简化执行计划,我们利用INDEX来优化GROUP BY语句。 例如:
set sql_mode='';
create index idx1 on t1(b);
explain format=json select t1.a from t1 group by t1.b order by 1;
| {
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "1.40"
},
"ordering_operation": {
"using_temporary_table": true,
"using_filesort": true,
"grouping_operation": {
"using_filesort": false,
...
drop index idx1 on t1;
1)如果连接表使用BNL(Batched Nestloop)/BKA(Batched Key Access)。 例如:
explain format=json select t2.a from t1, t1 as t2 group by t1.a;
| {
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "8.20"
},
"grouping_operation": {
"using_temporary_table": true,
"using_filesort": true,
"cost_info": {
"sort_cost": "4.00"
...
2) 如果GROUP BY的列不属于执行计划中的第一个连接表。 例如:
explain format=json select t2.a from t1, t1 as t2 group by t2.a;
| {
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "8.20"
},
"grouping_operation": {
"using_temporary_table": true,
"using_filesort": true,
"nested_loop": [
...
3) 如果GROUP BY语句使用的列与ORDER BY语句使用的列不同。 例如:
set sql_mode='';
explain format=json select t1.a from t1 group by t1.b order by t1.a;
| {
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "1.40"
},
"ordering_operation": {
"using_filesort": true,
"grouping_operation": {
"using_temporary_table": true,
"using_filesort": false,
...
4) 如果GROUP BY带有ROLLUP并且是基于多表外连接。 例如:
explain format=json select sum(t1.a) from t1 left join t1 as t2 on true group by t1.a with rollup;
| {
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "7.20"
},
"grouping_operation": {
"using_temporary_table": true,
"using_filesort": true,
"cost_info": {
"sort_cost": "4.00"
},
...
5) 如果GROUP BY语句使用的列来自于SCALAR SUBQUERY,并且没有被优化掉。 例如:
explain format=json select (select avg(a) from t1) as a from t1 group by a;
| {
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "3.40"
},
"grouping_operation": {
"using_temporary_table": true,
"using_filesort": true,
"cost_info": {
"sort_cost": "2.00"
},
...
set optimizer_switch='firstmatch=off,duplicateweedout=off';
explain format=json select * from t1 where a in (select b from t1);
| {
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "5.60"
},
"nested_loop": [
{
"rows_examined_per_scan": 1,
"materialized_from_subquery": {
"using_temporary_table": true,
"query_block": {
"table": {
"table_name": "t1",
"access_type": "ALL",
...
2) 如果semi-join执行方式为Duplicate Weedout 例如:
set optimizer_switch='firstmatch=off';
explain format=json select * from t1 where a in (select b from t1);
| {
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "4.80"
},
"duplicates_removal": {
"using_temporary_table": true,
"nested_loop": [
{
...
explain format=json select * from t1 union select * from t1;
| {
"query_block": {
"union_result": {
"using_temporary_table": true,
"table_name": "<union1,2>",
...
update t1, t1 as t2 set t1.a=3;
show status like 'CREATE%';
1) count(distinct *)
例如:
explain format=json select count(distinct a) from t1;
2) group_concat
例如:
explain format=json select group_concat(b) from t1;
总之,上面列出了10种情况,MySQL将利用内部临时表进行中间结果缓存,如果数据量比较大的话,内部临时表将会把数据存储在磁盘上,这样显然会对性能有所影响。为了尽可能的减少性能损失,我们需要尽量避免上述情况的出现。