show profile调优
有时候使用explain执行计划发现其实是命中了索引的,但是还是很慢,此时可以使用profile功能,show profile是mysql提供的可以用来分析当前会话中语句执行的资源消耗情况,如CPU、IO、IPC、SWAP以及发生的PAGE FAULTS等,可以用于SQL调优的测量
配置
默认情况下是关闭的
mysql> show variables like '%profiling%';
+------------------------+-------+
| Variable_name | Value |
+------------------------+-------+
| have_profiling | YES |
| profiling | OFF |
| profiling_history_size | 15 |
+------------------------+-------+
have_profiling 表示当前mysql版本支持show profile功能
profiling 表示当前功能是否开启
profiling_history_size 表示可以保留的历史数量(sql条数)
开启show profile
set profiling = 1;
查看
查看历史sql记录
-- 由于上边的配置是15,所以最多显示最近15条记录
show profiles;
根据query_id来分析该条sql的性能问题
show profile cpu,block io for query 18;
+----------------------+----------+----------+------------+--------------+---------------+
| Status | Duration | CPU_user | CPU_system | Block_ops_in | Block_ops_out |
+----------------------+----------+----------+------------+--------------+---------------+
| starting | 0.000084 | 0.000067 | 0.000013 | 0 | 0 |
| checking permissions | 0.000014 | 0.000008 | 0.000005 | 0 | 0 |
| Opening tables | 0.000039 | 0.000036 | 0.000003 | 0 | 0 |
| init | 0.000017 | 0.000015 | 0.000002 | 0 | 0 |
| System lock | 0.000009 | 0.000008 | 0.000001 | 0 | 0 |
| optimizing | 0.000004 | 0.000003 | 0.000001 | 0 | 0 |
| statistics | 0.000011 | 0.000010 | 0.000001 | 0 | 0 |
| preparing | 0.000009 | 0.000008 | 0.000001 | 0 | 0 |
| executing | 0.000003 | 0.000002 | 0.000001 | 0 | 0 |
| Sending data | 0.000039 | 0.000037 | 0.000001 | 0 | 0 |
| end | 0.000004 | 0.000003 | 0.000002 | 0 | 0 |
| query end | 0.000007 | 0.000006 | 0.000001 | 0 | 0 |
| closing tables | 0.000008 | 0.000007 | 0.000001 | 0 | 0 |
| freeing items | 0.000016 | 0.000007 | 0.000009 | 0 | 0 |
| cleaning up | 0.000015 | 0.000013 | 0.000001 | 0 | 0 |
+----------------------+----------+----------+------------+--------------+---------------+
该查询展示出了这条sql完整的执行生命周期
可以查询的类型有
all 显示所有开销 block io 显示块io开销 cpu 显示cpu开销 context switches 上下文切换开销 ipc 发送和接收相关开销 memory 内存开销 page faults 页面错误相关开销 source 显示Source_function、Source_file、Source_line相关开销 swaps 交换次数相关开销
PROFILING表
除了使用show profiles;来查询之外,还可以使用information_schema.PROFILING表来进行查询,且可以进行排序等操作
select state,sum(duration) as total_r,
round(100*sum(duration)/ (select sum(duration) from information_schema.PROFILING where query_id = 71),2) as pct_r,
count(*) as calls
from information_schema.PROFILING
where query_id = 71
group by state
order by total_r desc
如何判断哪些是出现问题的?
如果在执行过程中存在以下情况,则需要进行优化
-
converting HEAP to MyISAM 查询结果太大,内存不够用了,开始使用磁盘 -
create tmp table 创建临时表 -
Copying to tmp table on disk 将内存中的临时表复制到磁盘 -
locked