Commit e26b6c22 authored by dwentzel's avatar dwentzel
Browse files

updates

parent 21446be6
-- mysql sys: https://github.com/MarkLeith/mysql-sys
show variables like 'log_bin%';
show binary logs;
show processlist;
-- List long running queries
select
USER,
-- SUBSTRING_INDEX(HOST,':',1) AS HostName ,
HOST,
STATE,
COMMAND,
STATE,
INFO,
TIME
--from information_schema.PROCESSLIST where TIME > 1 --this is a blocking issue, use p_s.threads instead
from performance_schema.threads
Order by Time DESC;
-- List Threads by State
select
COUNT(USER) N,
USER,
HOST ,
STATE,
COMMAND,
STATE
--from information_schema.PROCESSLIST
from performance_schema.threads
Group By STATE
Order by STATE;
-- need mysqltuner.pl --will show how much RAM is needed for buffers, etc
-- setup
select * from performance_schema.setup_instruments; -- TIMED and ENABLED should both be YES
select * from performance_schema.setup_actors;
select * from performance_schema.setup_objects;
select * from performance_schema.setup_consumers;
-- global_instrumentation and thread_instrumentation must always be YES
-- "current" must be enabled for "history" and "history_long" to work
-- perf events not logged due to memory constraints
show status like 'perf%';
-- performance_schema affect on memory and performance
show engine performance_schema status;
select * from sys.`x$io_global_by_file_by_latency`;
select * from sys.`x$statement_analysis`;
select *, (max_latency/1000000000) as max_latency_ms, (avg_latency/1000000000) as avg_latency_ms
from sys.`x$statements_with_runtimes_in_95th_percentile`
where db = 'marketlink';
show databases;
select * from performance_schema.events_statements_summary_by_digest;
-- check what is going on
use performance_schema;
select th.processlist_user, ispl.host, ispl.db,ispl.user,th.processlist_id,esh.*
-- from information_schema.processlist ispl
from performance.threads
join threads th on ispl.id = th.processlist_id
join events_statements_current esh on th.thread_id = esh.thread_id; -- events_statements_history
select * from events_statements_history;
select * from events_statements_current;
select * from setup_users;
select * from setup_consumers;
select * from events_waits_history;
select * from mutex_instances;
select * from performance_schema.threads; -- set INSTRUMENTED = 'NO' for threads you don't want to instrument if history is being aged too quickly.
select * from events_statements_history_long;
-- who is doing what?
select * from sys.x$host_summary_by_statement_latency where max_latency > 0;
-- if stages is enabled we can what stages are having problems
select *, total_latency/total as latency_by_operation
from sys.x$host_summary_by_stages
where host like '%'
order by 6 desc limit 10;
-- where is it impacting?
select *, ((total_latency/total)/1000000000) as latency_by_operation_ms
from sys.x$host_summary_by_file_io_type
where host like '%'
order by latency_by_operation_ms desc;
-- view for statement analysis by host
CREATE
ALGORITHM = MERGE
DEFINER = `root`@`localhost`
SQL SECURITY INVOKER
VIEW `sys`.`x$statement_analysis_by_host`
AS
select
HOST as host,
EVENT_NAME as event ,
COUNT_STAR as exec_count,
SUM_TIMER_WAIT as total_latency ,
AVG_TIMER_WAIT as avg_latency ,
SUM_LOCK_TIME as lock_latency ,
SUM_ROWS_AFFECTED as changed_rows ,
SUM_ROWS_SENT as sent_rows ,
SUM_ROWS_EXAMINED as examined_rows,
SUM_CREATED_TMP_DISK_TABLES as tmp_table_on_disk,
SUM_CREATED_TMP_TABLES as tmp_table,
SUM_SELECT_FULL_JOIN as join_scan,
SUM_SELECT_FULL_RANGE_JOIN as join_range,
SUM_SELECT_RANGE_CHECK as join_select_check,
SUM_SELECT_SCAN as join_full_scan,
SUM_SORT_MERGE_PASSES as sort_passes,
SUM_SORT_SCAN as sort_scan,
SUM_NO_INDEX_USED as no_index_used,
SUM_NO_GOOD_INDEX_USED as no_good_index
from events_statements_summary_by_host_by_event_name
where COUNT_STAR > 0 order by avg_latency;
-- analysis most latency for the given host
select *
from sys.x$statement_analysis_by_host
where host like '%'
limit 5;
-- connect the dots using nesting_event_id
select * from events_waits_history;
select * from events_stages_history_long;
select * from events_statements_history_long;
-- find waits
SELECT
PROCESSLIST_ID,
ewh.THREAD_ID,
ewh.EVENT_NAME,
ewh.SOURCE,
sum(ewh.TIMER_WAIT)/1000000000 as Wait_ms,
ewh.OBJECT_SCHEMA,
ewh.OBJECT_NAME,
ewh.OBJECT_TYPE,
ewh.OPERATION
from events_waits_history ewh
join events_stages_history_long esth ON ewh.NESTING_EVENT_ID = esth.EVENT_ID
join events_statements_history_long esh ON esth.NESTING_EVENT_ID =esh.EVENT_ID
join threads th ON ewh.THREAD_ID = th.THREAD_ID
where PROCESSLIST_HOST like '%'
group by EVENT_NAME,PROCESSLIST_ID,ewh.THREAD_ID,ewh.EVENT_NAME,ewh.SOURCE, ewh.OBJECT_SCHEMA, ewh.OBJECT_NAME, ewh.OBJECT_TYPE, ewh.OPERATION
order by ewh.TIMER_WAIT desc limit 50;
-- global wait impacts
select events, total , (avg_latency/1000000000) as avg_latency_ms, (max_latency/1000000000) as max_latency_ms
from sys.x$waits_global_by_latency
order by avg_latency_ms desc
limit 10;
-- wait by table and operation
select table_name,count_read,sum_timer_read,count_write,sum_timer_write,sum_timer_misc
from x$ps_schema_table_statistics_io
where count_read > 0
order by sum_timer_misc desc limit 10;
-- initial review by SQL
select ss.*,(ss.full_scans/ss.total) * 100 as `FScan_%`
from sys.x$host_summary_by_statement_latency as ss
where max_latency > 0;
-- Slower tables
select
object_schema,
object_name,
count_star,
(sum_timer_wait/1000000000) as sum_timer_wait_ms,
((sum_timer_wait/count_star)/1000000000) as timer_wait_per_call_ms
from performance_schema.table_io_waits_summary_by_table
order by 4 desc limit 10;
-- Find the most expensive stages
select
*,
total_latency/total as latency_by_operation
from sys.x$host_summary_by_stages
where host like '%'
order by 6 desc limit 10;
-- Identify the file waits
select
event_name,
sum(total) as total,
sum(total_latency) as total_latency,
sum(max_latency) as max_latency,
((sum(total_latency)/sum(total))/1000000000) as latency_by_operation_ms
from sys.x$host_summary_by_file_io_type
where host like '%'
group by event_name
order by latency_by_operation_ms desc;
-- Identify the most expensive by type and host with details
Select
event,
sum(exec_count) as exec_count,
(sum(total_latency)/sum(exec_count)/1000000000) as total_latency_ms_by_exec,
(sum(lock_latency)/sum(exec_count)/1000000000) as lock_latency_ms_by_exec,
sum(changed_rows) as changed_rows,
sum(sent_rows) as sent_rows,
sum(examined_rows) as examined_rows,
sum(tmp_table_on_disk) as tmp_table_on_disk,
sum(tmp_table) as tmp_table,
sum(join_scan) as join_scan,
sum(join_range) as join_range,
sum(join_select_check) as join_select_check,
sum(join_full_scan) as join_full_scan,
sum(sort_passes) as sort_passes,
sum(no_index_used) as no_index_used,
sum(no_good_index) as no_good_index
from sys.x$statement_analysis_by_host
where host like '%'
group by event
order by 3 desc limit 50;
-- which wait event are most expensive
SELECT
PROCESSLIST_ID,
ewh.THREAD_ID,
ewh.EVENT_NAME,
ewh.SOURCE,
sum(ewh.TIMER_WAIT)/1000000000 as Wait_ms,
ewh.OBJECT_SCHEMA,
ewh.OBJECT_NAME,
ewh.OBJECT_TYPE,
ewh.OPERATION
from events_waits_history ewh
Join events_stages_history_long esth ON ewh.NESTING_EVENT_ID = esth.EVENT_ID
Join events_statements_history_long esh ON esth.NESTING_EVENT_ID =esh.EVENT_ID
Join threads th ON ewh.THREAD_ID = th.THREAD_ID
where PROCESSLIST_HOST like '%'
group by EVENT_NAME,PROCESSLIST_ID,ewh.THREAD_ID,ewh.EVENT_NAME,ewh.SOURCE, ewh.OBJECT_SCHEMA, ewh.OBJECT_NAME, ewh.OBJECT_TYPE, ewh.OPERATION
order by ewh.TIMER_WAIT desc limit 50;
-- Compare with what id GLOBALLY impacting
select
events,
total,
total_latency/1000000000 as total_latency_ms,
avg_latency/1000000000 as avg_latency_ms,
max_latency/1000000000 as max_latency_ms
from sys.x$waits_global_by_latency
order by avg_latency_ms desc
limit 50;
-- For each Event, what is happening
select
ewh.EVENT_NAME,
ewh.SOURCE,
sum(ewh.TIMER_WAIT)/1000000000 as time_wait_ms,
ewh.OBJECT_NAME,ewh.OBJECT_TYPE,ewh.OPERATION
from events_waits_history ewh
Join threads th on ewh.THREAD_ID = th.THREAD_ID
where EVENT_NAME like '%handler%'
group by EVENT_NAME,ewh.SOURCE,ewh.OBJECT_NAME,ewh.OBJECT_TYPE,ewh.OPERATION
order by time_wait_ms desc limit 20;
-- Time to see data files as well
select
ewh.EVENT_NAME,
ewh.SOURCE,
sum(ewh.TIMER_WAIT)/1000000000 as timer_wait_ms,
ewh.OBJECT_NAME,
ewh.OBJECT_TYPE,
ewh.OPERATION
from events_waits_history ewh
Join threads th on ewh.THREAD_ID = th.THREAD_ID
where EVENT_NAME like '%innodb_data_file%'
group by EVENT_NAME,ewh.SOURCE,ewh.OBJECT_NAME,ewh.OBJECT_TYPE,ewh.OPERATION
order by 3 desc limit 10;
-- And compare with GLOBAL wait for table
select
table_name,
count_read,
sum_timer_read/1000000000 as sum_timer_read_ms,
count_write,
sum_timer_write/1000000000 as sum_timer_write_ms,
sum_timer_misc /1000000000 as sum_timer_misc_ms
from sys.x$ps_schema_table_statistics_io
where count_read > 0
order by sum_timer_misc desc limit 10;
-- Memory by acct:
select thread_id,user,current_count_used,current_allocated,current_avg_alloc,total_allocated
from x$memory_by_thread_by_current_bytes order by current_allocated desc limit 10;
-- Memory by Event:
select event_name,current_count,current_alloc,high_count,high_alloc
from x$memory_global_by_current_allocated
where event_name not like '%performance_schema%'
order by current_alloc desc limit 10;
-- tables that may need ANALYZE
select
ST.TABLE_NAME,
INDEX_NAME,
SEQ_IN_INDEX,
COLUMN_NAME,
CARDINALITY,
TB.TABLE_ROWS,
(CARDINALITY/TB.TABLE_ROWS)*100 AS 'Card_%'
from information_schema.STATISTICS ST
JOIN information_schema.TABLES TB on ST.TABLE_SCHEMA=TB.TABLE_SCHEMA AND ST.TABLE_NAME=TB.TABLE_NAME
where ST.TABLE_SCHEMA='marketlink'
ORDER BY ST.TABLE_NAME,INDEX_NAME,SEQ_IN_INDEX;
-- innodb table statistics
select *
from information_schema.INNODB_SYS_TABLESTATS
where name like 'marketlink/%';
-- innodb transactions
select * from information_schema.INNODB_TRX;
select * from information_schema.INNODB_LOCKS;
select * from information_schema.INNODB_LOCK_WAITS;
SELECT CONCAT(ROUND(KBS/POWER(1024,IF(Power1024<0,0,
IF(Power1024>3,0,Power1024)))+0.49999),SUBSTR(' KMG',IF(Power1024<0,0,
IF(Power1024>3,0,Power1024))+1,1)) recommended_innodb_buffer_pool_size
FROM (SELECT SUM(data_length+index_length) KBS FROM information_schema.tables
WHERE engine='InnoDB') A,(SELECT 2 Power1024) B;
CREATE VIEW processlist_full AS
SELECT pps.thread_id AS thd_id,
pps.processlist_id AS conn_id,
IF(pps.name = 'thread/sql/one_connection',
CONCAT(pps.processlist_user, '@', pps.processlist_host),
REPLACE(pps.name, 'thread/', '')) user,
pps.processlist_db AS db,
pps.processlist_command AS command,
pps.processlist_state AS state,
pps.processlist_time AS time,
format_statement(pps.processlist_info) AS current_statement,
IF(esc.timer_wait IS NOT NULL,
format_statement(esc.sql_text),
NULL) AS last_statement,
IF(esc.timer_wait IS NOT NULL,
format_time(esc.timer_wait),
NULL) as last_statement_latency,
format_time(esc.lock_time) AS lock_latency,
esc.rows_examined,
esc.rows_sent,
esc.rows_affected,
esc.created_tmp_tables AS tmp_tables,
esc.created_tmp_disk_tables as tmp_disk_tables,
IF(esc.no_good_index_used > 0 OR esc.no_index_used > 0,
'YES', 'NO') AS full_scan,
ewc.event_name AS last_wait,
IF(ewc.timer_wait IS NULL AND ewc.event_name IS NOT NULL,
'Still Waiting',
format_time(ewc.timer_wait)) last_wait_latency,
ewc.source
FROM performance_schema.threads AS pps
LEFT JOIN performance_schema.events_waits_current AS ewc USING (thread_id)
LEFT JOIN performance_schema.events_statements_current as esc USING (thread_id)
ORDER BY pps.processlist_time DESC, last_wait_latency DESC;
-- custom show processlist.
CREATE OR REPLACE SQL SECURITY INVOKER VIEW custom_showprocesslist AS
SELECT t.PROCESSLIST_ID AS Id, t.PROCESSLIST_USER AS User, t.PROCESSLIST_HOST AS Host,
t.PROCESSLIST_DB AS db, t.PROCESSLIST_COMMAND AS Command,
t.PROCESSLIST_TIME AS Time, ps_helper.format_time(SUM(SUM_TIMER_WAIT)) AS TotalExecTime,
IF(t.PROCESSLIST_INFO IS NULL, '', t.PROCESSLIST_STATE) AS State,
IF(s.TIMER_END IS NULL, 'YES', 'NO') AS IsExecuting,
SUM(ste.COUNT_STAR) AS TotalStatements,
s.ERRORS, SUM(ste.SUM_ERRORS) AS TotalErrors,
s.WARNINGS, SUM(ste.SUM_WARNINGS) AS TotalWarnings,
s.ROWS_AFFECTED, SUM(ste.SUM_ROWS_AFFECTED) AS TotalRowsAffected,
s.ROWS_SENT, SUM(ste.SUM_ROWS_SENT) AS TotalRowsSent,
s.ROWS_EXAMINED, SUM(ste.SUM_ROWS_EXAMINED) AS TotalRowsExamnied,
s.CREATED_TMP_DISK_TABLES, SUM(ste.SUM_CREATED_TMP_DISK_TABLES) AS TotalTmpDiskTables,
s.CREATED_TMP_TABLES, SUM(ste.SUM_CREATED_TMP_TABLES) AS TotalTmpTables,
s.SELECT_FULL_JOIN, SUM(ste.SUM_SELECT_FULL_JOIN) AS TotalFullJoin,
s.SELECT_FULL_RANGE_JOIN, SUM(ste.SUM_SELECT_FULL_RANGE_JOIN) AS TotalFullRangeJoin,
s.SELECT_RANGE, SUM(ste.SUM_SELECT_RANGE) AS TotalRange,
s.SELECT_RANGE_CHECK, SUM(ste.SUM_SELECT_RANGE_CHECK) AS TotalRangeCheck,
s.SELECT_SCAN, SUM(ste.SUM_SELECT_SCAN) AS TotalScan,
s.SORT_MERGE_PASSES, SUM(ste.SUM_SORT_MERGE_PASSES) AS TotalSortMergePasses,
s.SORT_RANGE, SUM(ste.SUM_SORT_RANGE) AS TotalSortRange,
s.SORT_ROWS, SUM(ste.SUM_SORT_ROWS) AS TotalSortRows,
s.SORT_SCAN, SUM(ste.SUM_SORT_SCAN) AS TotalSortScan,
s.NO_INDEX_USED, SUM(ste.SUM_NO_INDEX_USED) AS TotalNoIndex,
s.NO_GOOD_INDEX_USED, SUM(ste.SUM_NO_GOOD_INDEX_USED) AS TotalNoGoodIndex,
LEFT(s.SQL_TEXT, 100) AS Info
FROM performance_schema.threads t
INNER JOIN performance_schema.events_statements_current s USING (THREAD_ID)
INNER JOIN performance_schema.events_statements_summary_by_thread_by_event_name ste
USING (THREAD_ID)
WHERE t.TYPE = 'FOREGROUND'
GROUP BY THREAD_ID;
-- view for statement analysis by host
CREATE
ALGORITHM = MERGE
DEFINER = `root`@`localhost`
SQL SECURITY INVOKER
VIEW `sys`.`x$statement_analysis_by_host`
AS
select
HOST as host,
EVENT_NAME as event ,
COUNT_STAR as exec_count,
SUM_TIMER_WAIT as total_latency ,
AVG_TIMER_WAIT as avg_latency ,
SUM_LOCK_TIME as lock_latency ,
SUM_ROWS_AFFECTED as changed_rows ,
SUM_ROWS_SENT as sent_rows ,
SUM_ROWS_EXAMINED as examined_rows,
SUM_CREATED_TMP_DISK_TABLES as tmp_table_on_disk,
SUM_CREATED_TMP_TABLES as tmp_table,
SUM_SELECT_FULL_JOIN as join_scan,
SUM_SELECT_FULL_RANGE_JOIN as join_range,
SUM_SELECT_RANGE_CHECK as join_select_check,
SUM_SELECT_SCAN as join_full_scan,
SUM_SORT_MERGE_PASSES as sort_passes,
SUM_SORT_SCAN as sort_scan,
SUM_NO_INDEX_USED as no_index_used,
SUM_NO_GOOD_INDEX_USED as no_good_index
from events_statements_summary_by_host_by_event_name
where COUNT_STAR > 0 order by avg_latency;
CREATE VIEW processlist_full AS
SELECT pps.thread_id AS thd_id,
pps.processlist_id AS conn_id,
IF(pps.name = 'thread/sql/one_connection',
CONCAT(pps.processlist_user, '@', pps.processlist_host),
REPLACE(pps.name, 'thread/', '')) user,
pps.processlist_db AS db,
pps.processlist_command AS command,
pps.processlist_state AS state,
pps.processlist_time AS time,
format_statement(pps.processlist_info) AS current_statement,
IF(esc.timer_wait IS NOT NULL,
format_statement(esc.sql_text),
NULL) AS last_statement,
IF(esc.timer_wait IS NOT NULL,
format_time(esc.timer_wait),
NULL) as last_statement_latency,
format_time(esc.lock_time) AS lock_latency,
esc.rows_examined,
esc.rows_sent,
esc.rows_affected,
esc.created_tmp_tables AS tmp_tables,
esc.created_tmp_disk_tables as tmp_disk_tables,
IF(esc.no_good_index_used > 0 OR esc.no_index_used > 0,
'YES', 'NO') AS full_scan,
ewc.event_name AS last_wait,
IF(ewc.timer_wait IS NULL AND ewc.event_name IS NOT NULL,
'Still Waiting',
format_time(ewc.timer_wait)) last_wait_latency,
ewc.source
FROM performance_schema.threads AS pps
LEFT JOIN performance_schema.events_waits_current AS ewc USING (thread_id)
LEFT JOIN performance_schema.events_statements_current as esc USING (thread_id)
ORDER BY pps.processlist_time DESC, last_wait_latency DESC;
-- custom show processlist.
CREATE OR REPLACE SQL SECURITY INVOKER VIEW custom_showprocesslist AS
SELECT t.PROCESSLIST_ID AS Id, t.PROCESSLIST_USER AS User, t.PROCESSLIST_HOST AS Host,
t.PROCESSLIST_DB AS db, t.PROCESSLIST_COMMAND AS Command,
t.PROCESSLIST_TIME AS Time, ps_helper.format_time(SUM(SUM_TIMER_WAIT)) AS TotalExecTime,
IF(t.PROCESSLIST_INFO IS NULL, '', t.PROCESSLIST_STATE) AS State,
IF(s.TIMER_END IS NULL, 'YES', 'NO') AS IsExecuting,
SUM(ste.COUNT_STAR) AS TotalStatements,
s.ERRORS, SUM(ste.SUM_ERRORS) AS TotalErrors,
s.WARNINGS, SUM(ste.SUM_WARNINGS) AS TotalWarnings,
s.ROWS_AFFECTED, SUM(ste.SUM_ROWS_AFFECTED) AS TotalRowsAffected,
s.ROWS_SENT, SUM(ste.SUM_ROWS_SENT) AS TotalRowsSent,
s.ROWS_EXAMINED, SUM(ste.SUM_ROWS_EXAMINED) AS TotalRowsExamnied,
s.CREATED_TMP_DISK_TABLES, SUM(ste.SUM_CREATED_TMP_DISK_TABLES) AS TotalTmpDiskTables,
s.CREATED_TMP_TABLES, SUM(ste.SUM_CREATED_TMP_TABLES) AS TotalTmpTables,
s.SELECT_FULL_JOIN, SUM(ste.SUM_SELECT_FULL_JOIN) AS TotalFullJoin,
s.SELECT_FULL_RANGE_JOIN, SUM(ste.SUM_SELECT_FULL_RANGE_JOIN) AS TotalFullRangeJoin,
s.SELECT_RANGE, SUM(ste.SUM_SELECT_RANGE) AS TotalRange,
s.SELECT_RANGE_CHECK, SUM(ste.SUM_SELECT_RANGE_CHECK) AS TotalRangeCheck,
s.SELECT_SCAN, SUM(ste.SUM_SELECT_SCAN) AS TotalScan,
s.SORT_MERGE_PASSES, SUM(ste.SUM_SORT_MERGE_PASSES) AS TotalSortMergePasses,
s.SORT_RANGE, SUM(ste.SUM_SORT_RANGE) AS TotalSortRange,
s.SORT_ROWS, SUM(ste.SUM_SORT_ROWS) AS TotalSortRows,
s.SORT_SCAN, SUM(ste.SUM_SORT_SCAN) AS TotalSortScan,
s.NO_INDEX_USED, SUM(ste.SUM_NO_INDEX_USED) AS TotalNoIndex,
s.NO_GOOD_INDEX_USED, SUM(ste.SUM_NO_GOOD_INDEX_USED) AS TotalNoGoodIndex,
LEFT(s.SQL_TEXT, 100) AS Info
FROM performance_schema.threads t
INNER JOIN performance_schema.events_statements_current s USING (THREAD_ID)
INNER JOIN performance_schema.events_statements_summary_by_thread_by_event_name ste
USING (THREAD_ID)
WHERE t.TYPE = 'FOREGROUND'
GROUP BY THREAD_ID;
use performance_schema;
select * from setup_instruments where enabled = 'YES'; -- shows you what is currently enabled in instrumentation
select * from setup_consumers; -- which consumers are enabled
-- items that really should be enabled but probably are not
-- events_statements_history should be enabled
update setup_consumers set Enabled = 'YES' where name = 'events_statements_history' LIMIT 1;
commit;
-- turn on all monitors for stage events.
-- contains most of the lighter-weight instruments and isn't too costly
update performance_schema.setup_instruments set enabled='YES', timed='YES' where ... ;
commit;
-- for the consumers you probably want at least events_statements_history
update performance_schema.setup_consumers set enabled='YES' where ...;
\ No newline at end of file
SHOW ENGINE performance_schema status;
show status like 'perf%' -- shows lost data due to load/memory constraints.
-- setup
select * from performance_schema.setup_instruments; -- TIMED and ENABLED should both be YES
select * from performance_schema.setup_actors;
select * from performance_schema.setup_objects;
select * from performance_schema.setup_consumers;
-- global_instrumentation and thread_instrumentation must always be YES
-- "current" must be enabled for "history" and "history_long" to work
\ No newline at end of file
-- list long running queries
select
processlist_user,
SUBSTRING_INDEX(processlist_host,':',1) AS HostName ,
processlist_host,
processlist_STATE,
processlist_COMMAND,
processlist_info,
processlist_time
from performance_schema.threads
where (processlist_user IS NOT NULL)
Order by processlist_time DESC;
-- List Threads by State
select
COUNT(processlist_USER) N,
processlist_USER,
processlist_HOST ,
processlist_STATE,
processlist_COMMAND,
processlist_STATE
from performance_schema.threads
Group By processlist_STATE
Order by processlist_STATE;
-- NOW: current state
-- what is currently executing, waiting, etc. This can be snapshot periodically during a load test, maybe even
-- 15 seconds and then queried for interesting trends later.
select th.processlist_user, ispl.host, ispl.db,ispl.user,th.processlist_id,esh.*
-- processlist is known to cause blocking. this query should be rewritten to use performance_schema.threads
from information_schema.processlist ispl
join threads th on ispl.id = th.processlist_id
join events_statements_current esh on th.thread_id = esh.thread_id; -- events_statements_history
-- which wait event are most expensive
SELECT
PROCESSLIST_ID,
ewh.THREAD_ID,
ewh.EVENT_NAME,
ewh.SOURCE,
sum(ewh.TIMER_WAIT)/1000000000 as Wait_ms,
ewh.OBJECT_SCHEMA,
ewh.OBJECT_NAME,