Analyzing Queries
You can use the performance schema and sys schema to analyze queries executed on the DB system.
The performance schema provides a way to inspect internal execution of the server at runtime, and it focuses primarily on performance data while the sys schema helps to interpret data collected by the performance schema.
For example, if you want to find the query that consumes most of the execution time (latency), run the following:
SELECT schema_name, format_pico_time(total_latency) tot_lat,
exec_count, format_pico_time(total_latency/exec_count)
latency_per_call, query_sample_text
FROM sys.x$statements_with_runtimes_in_95th_percentile as t1
JOIN performance_schema.events_statements_summary_by_digest as t2 on t2.digest=t1.digest
WHERE schema_name not in ('performance_schema', 'sys')
ORDER BY (total_latency/exec_count) desc limit 1\G
*************************** 1. row ***************************
schema_name: employees
tot_lat: 21.54 s
exec_count: 4
latency_per_call: 5.38 s
query_sample_text: select * from salaries where salary > 80000
1 row in set (0.0127 sec)
Sys schema also contains a statement analysis view that you can use
to hunt the bad queries. For
example:
SELECT * FROM sys.statement_analysis
WHERE db notin('performance_schema','sys')limit1\G
***************************1.row***************************
query: SELECT`new_table`.`title`,...`title`ORDERBY`salary`DESC
db: employees
full_scan:
exec_count: 11
err_count: 0
warn_count: 0
total_latency: 38.96 s
max_latency: 5.15 s
avg_latency: 3.54 s
lock_latency: 33.00 us
cpu_latency: 0 ps
rows_sent: 77
rows_sent_avg: 7
rows_examined: 13053117
rows_examined_avg: 1186647
rows_affected: 0
rows_affected_avg: 0
tmp_tables: 22
tmp_disk_tables: 11
rows_sorted: 77
sort_merge_passes: 0
digest: 922701de9e5c51847f9f7de245b88fef4080b515ba8805082cd90c32830714eb
first_seen: 2022-10-1220:45:50.770465
last_seen: 2022-10-1311:49:13.1402281rowinset(0.0022 sec)
Related Topics