暂无图片
暂无图片
暂无图片
暂无图片
暂无图片

MySQL 资源消耗查询语句

原创 SQLDEV社区 2022-11-25
593

p.p1 {margin: 0.0px 0.0px 0.0px 0.0px; font: 12.0px 'Helvetica Neue'} p.p2 {margin: 0.0px 0.0px 0.0px 0.0px; font: 12.0px 'Helvetica Neue'; min-height: 14.0px}

1.查看哪些sql执行最多

SELECT SCHEMA_NAME,DIGEST_TEXT,COUNT_STAR,SUM_ROWS_SENT,SUM_ROWS_EXAMINED,FIRST_SEEN,LAST_SEEN

FROM performance_schema.events_statements_summary_by_digest

where SCHEMA_NAME is not null and SCHEMA_NAME !='information_schema'

ORDER BY COUNT_STAR desc LIMIT 1;


2.哪个SQL平均响应时间最多

SELECT SCHEMA_NAME,DIGEST_TEXT,COUNT_STAR,AVG_TIMER_WAIT,SUM_ROWS_SENT,SUM_ROWS_EXAMINED,FIRST_SEEN,LAST_SEEN

FROM performance_schema.events_statements_summary_by_digest

where SCHEMA_NAME is not null and SCHEMA_NAME !='information_schema'

ORDER BY AVG_TIMER_WAIT desc LIMIT 1;


3.哪个SQL扫描的行数最多(IO消耗)

SELECT SCHEMA_NAME,DIGEST_TEXT,COUNT_STAR,AVG_TIMER_WAIT,SUM_ROWS_SENT,SUM_ROWS_EXAMINED,FIRST_SEEN,LAST_SEEN

FROM performance_schema.events_statements_summary_by_digest

where SCHEMA_NAME is not null and SCHEMA_NAME !='information_schema'

ORDER BY SUM_ROWS_EXAMINED desc LIMIT 1;


4.哪个SQL使用的临时表最多

SELECT SCHEMA_NAME,DIGEST_TEXT,SUM_CREATED_TMP_DISK_TABLES,SUM_CREATED_TMP_TABLES,FIRST_SEEN,LAST_SEEN

FROM performance_schema.events_statements_summary_by_digest

where SCHEMA_NAME is not null and SCHEMA_NAME !='information_schema'

ORDER BY SUM_CREATED_TMP_DISK_TABLES desc LIMIT 1;


5.哪个SQL返回的结果集最多(net消耗)

SELECT SCHEMA_NAME,DIGEST_TEXT,COUNT_STAR,SUM_ROWS_SENT,SUM_ROWS_SENT,FIRST_SEEN,LAST_SEEN

FROM performance_schema.events_statements_summary_by_digest

where SCHEMA_NAME is not null and SCHEMA_NAME !='information_schema'

ORDER BY SUM_ROWS_SENT desc LIMIT 1;


6.哪个SQL排序数最多(CPU消耗)

SELECT SCHEMA_NAME,DIGEST_TEXT,COUNT_STAR,SUM_ROWS_SENT,SUM_SORT_ROWS,FIRST_SEEN,LAST_SEEN

FROM performance_schema.events_statements_summary_by_digest

where SCHEMA_NAME is not null and SCHEMA_NAME !='information_schema'

ORDER BY SUM_SORT_ROWS desc LIMIT 5;


7.哪个表、文件逻辑IO最多(热数据)

SELECT FILE_NAME,EVENT_NAME,COUNT_READ,SUM_NUMBER_OF_BYTES_READ,COUNT_WRITE,SUM_NUMBER_OF_BYTES_WRITE

FROM performance_schema.file_summary_by_instance

ORDER BY SUM_NUMBER_OF_BYTES_READ+SUM_NUMBER_OF_BYTES_WRITE DESC LIMIT 2;


8.哪个索引使用最多

SELECT OBJECT_NAME, INDEX_NAME, COUNT_FETCH, COUNT_INSERT, COUNT_UPDATE, COUNT_DELETE

FROM performance_schema.table_io_waits_summary_by_index_usage

ORDER BY SUM_TIMER_WAIT DESC limit 1;


9.哪个索引没有使用过

SELECT OBJECT_SCHEMA, OBJECT_NAME, INDEX_NAME

FROM performance_schema.table_io_waits_summary_by_index_usage

WHERE INDEX_NAME IS NOT NULL AND COUNT_STAR = 0 AND OBJECT_SCHEMA <> 'mysql'

ORDER BY OBJECT_SCHEMA,OBJECT_NAME;


10.哪个等待事件消耗的时间最多

SELECT EVENT_NAME, COUNT_STAR, SUM_TIMER_WAIT, AVG_TIMER_WAIT

FROM events_waits_summary_global_by_event_name

WHERE event_name != 'idle'he

ORDER BY SUM_TIMER_WAIT DESC LIMIT 1;


数据库堡垒机:sqldev.info

产品试用/商务合作:chengyong@shuaninfo.com

「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

评论