1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82
|
-- Copyright (c) 2014, 2015, Oracle and/or its affiliates. All rights reserved.
--
-- This program is free software; you can redistribute it and/or modify
-- it under the terms of the GNU General Public License as published by
-- the Free Software Foundation; version 2 of the License.
--
-- This program is distributed in the hope that it will be useful,
-- but WITHOUT ANY WARRANTY; without even the implied warranty of
-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
-- GNU General Public License for more details.
--
-- You should have received a copy of the GNU General Public License
-- along with this program; if not, write to the Free Software
-- Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA
--
-- View: statements_with_full_table_scans
--
-- Lists all normalized statements that use have done a full table scan
-- ordered by number the percentage of times a full scan was done,
-- then by the statement latency.
--
-- This view ignores SHOW statements, as these always cause a full table scan,
-- and there is nothing that can be done about this.
--
-- mysql> select * from statements_with_full_table_scans limit 1\G
-- *************************** 1. row ***************************
-- query: SELECT * FROM `schema_tables_w ... ex_usage` . `COUNT_READ` DESC
-- db: sys
-- exec_count: 1
-- total_latency: 88.20 ms
-- no_index_used_count: 1
-- no_good_index_used_count: 0
-- no_index_used_pct: 100
-- rows_sent: 0
-- rows_examined: 1501
-- rows_sent_avg: 0
-- rows_examined_avg: 1501
-- first_seen: 2014-03-07 13:58:20
-- last_seen: 2014-03-07 13:58:20
-- digest: 64baecd5c1e1e1651a6b92e55442a288
--
CREATE OR REPLACE
ALGORITHM = MERGE
DEFINER = 'mariadb.sys'@'localhost'
SQL SECURITY INVOKER
VIEW statements_with_full_table_scans (
query,
db,
exec_count,
total_latency,
no_index_used_count,
no_good_index_used_count,
no_index_used_pct,
rows_sent,
rows_examined,
rows_sent_avg,
rows_examined_avg,
first_seen,
last_seen,
digest
) AS
SELECT sys.format_statement(DIGEST_TEXT) AS query,
SCHEMA_NAME as db,
COUNT_STAR AS exec_count,
format_pico_time(SUM_TIMER_WAIT) AS total_latency,
SUM_NO_INDEX_USED AS no_index_used_count,
SUM_NO_GOOD_INDEX_USED AS no_good_index_used_count,
ROUND(IFNULL(SUM_NO_INDEX_USED / NULLIF(COUNT_STAR, 0), 0) * 100) AS no_index_used_pct,
SUM_ROWS_SENT AS rows_sent,
SUM_ROWS_EXAMINED AS rows_examined,
ROUND(SUM_ROWS_SENT/COUNT_STAR) AS rows_sent_avg,
ROUND(SUM_ROWS_EXAMINED/COUNT_STAR) AS rows_examined_avg,
FIRST_SEEN as first_seen,
LAST_SEEN as last_seen,
DIGEST AS digest
FROM performance_schema.events_statements_summary_by_digest
WHERE (SUM_NO_INDEX_USED > 0
OR SUM_NO_GOOD_INDEX_USED > 0)
AND DIGEST_TEXT NOT LIKE 'SHOW%'
ORDER BY no_index_used_pct DESC, total_latency DESC;
|