MySQL问题排查SQL

查看当前应用连接,连接数突增排查

1
select user,SUBSTRING_INDEX(host,':',1) as ip , count(*) as count,db from information_schema.processlist where host not in ('localhost') and user not in ('replicater') group by ip order by count;

查看当前应用连接,连接数突增排查

查看表所属及大概行数,一般加字段索引时做参考

1
select TABLE_SCHEMA,TABLE_NAME,TABLE_ROWS from information_schema.tables where TABLE_NAME='表名';

查看表所属及大概行数,一般加字段索引时做参考

查看表碎片,是否需要整理表释放物理空间

1
select table_name,table_rows,concat(round(DATA_LENGTH/1024/1024, 2), 'MB') as size,DATA_FREE/1024/1024 AS data_free_MB from information_schema.TABLES where table_schema='库名' order by DATA_LENGTH desc;

查看表碎片,是否需要整理表释放物理空间

当前有没有锁

1
select * from information_schema.innodb_locks;

当前有没有锁

当前锁堵塞情况

1
select * from information_schema.innodb_lock_waits;

当前锁堵塞情况

当前锁等待详细信息

1
select it.trx_mysql_thread_id, il.lock_id, il.lock_table, il.lock_mode, il.lock_type, it.trx_state, pl.USER||'@'||pl.HOST as user_host, pl.db, pl.command, pl.info, it.trx_started, it.trx_wait_started, now()-trx_wait_started as wait_seconds, il.lock_index, it.trx_weight, it.trx_rows_locked, it.trx_rows_modified from information_schema.INNODB_TRX it,information_schema.innodb_locks il,information_schema.processlist pl where it.trx_id = il.lock_trx_id and it.trx_mysql_thread_id = pl.id\G

当前锁等待详细信息

最近一次死锁、未提交事物、CHECKPIONT、BUFFER POOL等

1
show engine innodb status\G

最近一次死锁、未提交事物、CHECKPIONT、BUFFER POOL等

过滤无用线程信息可用pager

1
pager grep -v Sleep;show processlist;

过滤无用线程信息可用pager

查看当前运行的详细SQL

1
SELECT * FROM INFORMATION_SCHEMA.PROCESSLIST WHERE info is not null\G

查看当前运行的详细SQL

查看某条sql各阶段执行时间,可开启profiling功能

1
set global profiling=on;

查看用户信息

1
select user,host,authentication_string from mysql.user group by user;

查看用户信息

查看哪些sql执行最多次

1
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;

查看哪些sql执行最多次

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

1
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\G

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

哪个SQL使用的临时表最多

1
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\G

哪个SQL使用的临时表最多

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

1
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\G

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

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

1
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 1\G

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

本文标题:MySQL问题排查SQL

文章作者:王洪博

发布时间:2019年09月19日 - 15:09

最后更新:2019年09月19日 - 07:09

原始链接:http://whb1990.github.io/posts/81d4f14b.html

▄︻┻═┳一如果你喜欢这篇文章,请点击下方"打赏"按钮请我喝杯 ☕
0%