diff options
author | Daniel Baumann <daniel.baumann@progress-linux.org> | 2024-05-04 18:00:34 +0000 |
---|---|---|
committer | Daniel Baumann <daniel.baumann@progress-linux.org> | 2024-05-04 18:00:34 +0000 |
commit | 3f619478f796eddbba6e39502fe941b285dd97b1 (patch) | |
tree | e2c7b5777f728320e5b5542b6213fd3591ba51e2 /scripts/sys_schema/views | |
parent | Initial commit. (diff) | |
download | mariadb-3f619478f796eddbba6e39502fe941b285dd97b1.tar.xz mariadb-3f619478f796eddbba6e39502fe941b285dd97b1.zip |
Adding upstream version 1:10.11.6.upstream/1%10.11.6upstream
Signed-off-by: Daniel Baumann <daniel.baumann@progress-linux.org>
Diffstat (limited to 'scripts/sys_schema/views')
108 files changed, 7365 insertions, 0 deletions
diff --git a/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_schema.sql b/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_schema.sql new file mode 100644 index 00000000..46f7cdd0 --- /dev/null +++ b/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_schema.sql @@ -0,0 +1,65 @@ +-- Copyright (c) 2014, 2016, 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: innodb_buffer_stats_by_schema +-- +-- Summarizes the output of the INFORMATION_SCHEMA.INNODB_BUFFER_PAGE +-- table, aggregating by schema +-- +-- +-- mysql> select * from innodb_buffer_stats_by_schema; +-- +--------------------------+------------+------------+-------+--------------+-----------+-------------+ +-- | object_schema | allocated | data | pages | pages_hashed | pages_old | rows_cached | +-- +--------------------------+------------+------------+-------+--------------+-----------+-------------+ +-- | mem30_trunk__instruments | 1.69 MiB | 510.03 KiB | 108 | 108 | 108 | 3885 | +-- | InnoDB System | 688.00 KiB | 351.62 KiB | 43 | 43 | 43 | 862 | +-- | mem30_trunk__events | 80.00 KiB | 21.61 KiB | 5 | 5 | 5 | 229 | +-- +--------------------------+------------+------------+-------+--------------+-----------+-------------+ +-- + +DELIMITER $$ + +BEGIN NOT ATOMIC + DECLARE EXIT HANDLER FOR SQLEXCEPTION + BEGIN + END; +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW innodb_buffer_stats_by_schema ( + object_schema, + allocated, + data, + pages, + pages_hashed, + pages_old, + rows_cached +) AS +SELECT IF(LOCATE('.', ibp.table_name) = 0, 'InnoDB System', REPLACE(SUBSTRING_INDEX(ibp.table_name, '.', 1), '`', '')) AS object_schema, + sys.format_bytes(SUM(IF(ibp.compressed_size = 0, 16384, compressed_size))) AS allocated, + sys.format_bytes(SUM(ibp.data_size)) AS data, + COUNT(ibp.page_number) AS pages, + COUNT(IF(ibp.is_hashed = 'YES', 1, NULL)) AS pages_hashed, + COUNT(IF(ibp.is_old = 'YES', 1, NULL)) AS pages_old, + ROUND(SUM(ibp.number_records)/COUNT(DISTINCT ibp.index_name)) AS rows_cached + FROM information_schema.innodb_buffer_page ibp + WHERE table_name IS NOT NULL + GROUP BY object_schema + ORDER BY SUM(IF(ibp.compressed_size = 0, 16384, compressed_size)) DESC; +END$$ +DELIMITER ; + diff --git a/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_table.sql b/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_table.sql new file mode 100644 index 00000000..be104fb5 --- /dev/null +++ b/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_table.sql @@ -0,0 +1,67 @@ +-- Copyright (c) 2014, 2016, 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: innodb_buffer_stats_by_table +-- +-- Summarizes the output of the INFORMATION_SCHEMA.INNODB_BUFFER_PAGE +-- table, aggregating by schema and table name +-- +-- mysql> select * from innodb_buffer_stats_by_table; +-- +--------------------------+------------------------------------+------------+-----------+-------+--------------+-----------+-------------+ +-- | object_schema | object_name | allocated | data | pages | pages_hashed | pages_old | rows_cached | +-- +--------------------------+------------------------------------+------------+-----------+-------+--------------+-----------+-------------+ +-- | InnoDB System | SYS_COLUMNS | 128.00 KiB | 98.97 KiB | 8 | 8 | 8 | 1532 | +-- | InnoDB System | SYS_FOREIGN | 128.00 KiB | 55.48 KiB | 8 | 8 | 8 | 172 | +-- | InnoDB System | SYS_TABLES | 128.00 KiB | 56.18 KiB | 8 | 8 | 8 | 365 | +-- | InnoDB System | SYS_INDEXES | 112.00 KiB | 76.16 KiB | 7 | 7 | 7 | 1046 | +-- | mem30_trunk__instruments | agentlatencytime | 96.00 KiB | 28.83 KiB | 6 | 6 | 6 | 252 | +-- | mem30_trunk__instruments | binlogspaceusagedata | 96.00 KiB | 22.54 KiB | 6 | 6 | 6 | 196 | +-- | mem30_trunk__instruments | connectionsdata | 96.00 KiB | 36.68 KiB | 6 | 6 | 6 | 276 | +-- ... +-- +--------------------------+------------------------------------+------------+-----------+-------+--------------+-----------+-------------+ +-- + +DELIMITER $$ +BEGIN NOT ATOMIC +DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN END; +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW innodb_buffer_stats_by_table ( + object_schema, + object_name, + allocated, + data, + pages, + pages_hashed, + pages_old, + rows_cached +) AS +SELECT IF(LOCATE('.', ibp.table_name) = 0, 'InnoDB System', REPLACE(SUBSTRING_INDEX(ibp.table_name, '.', 1), '`', '')) AS object_schema, + REPLACE(SUBSTRING_INDEX(ibp.table_name, '.', -1), '`', '') AS object_name, + sys.format_bytes(SUM(IF(ibp.compressed_size = 0, 16384, compressed_size))) AS allocated, + sys.format_bytes(SUM(ibp.data_size)) AS data, + COUNT(ibp.page_number) AS pages, + COUNT(IF(ibp.is_hashed = 'YES', 1, NULL)) AS pages_hashed, + COUNT(IF(ibp.is_old = 'YES', 1, NULL)) AS pages_old, + ROUND(SUM(ibp.number_records)/COUNT(DISTINCT ibp.index_name)) AS rows_cached + FROM information_schema.innodb_buffer_page ibp + WHERE table_name IS NOT NULL + GROUP BY object_schema, object_name + ORDER BY SUM(IF(ibp.compressed_size = 0, 16384, compressed_size)) DESC; +END$$ +DELIMITER ;
\ No newline at end of file diff --git a/scripts/sys_schema/views/i_s/innodb_lock_waits.sql b/scripts/sys_schema/views/i_s/innodb_lock_waits.sql new file mode 100644 index 00000000..493eacfc --- /dev/null +++ b/scripts/sys_schema/views/i_s/innodb_lock_waits.sql @@ -0,0 +1,124 @@ +-- 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: innodb_lock_waits +-- +-- Give a snapshot of which InnoDB locks transactions are waiting for. +-- The lock waits are ordered by the age of the lock descending. +-- +-- Versions: 5.1+ (5.1 requires InnoDB Plugin with I_S tables) +-- +-- mysql> SELECT * FROM x$innodb_lock_waits\G +-- *************************** 1. row *************************** +-- wait_started: 2014-11-11 13:39:20 +-- wait_age: 00:00:07 +-- wait_age_secs: 7 +-- locked_table: `db1`.`t1` +-- locked_index: PRIMARY +-- locked_type: RECORD +-- waiting_trx_id: 867158 +-- waiting_trx_started: 2014-11-11 13:39:15 +-- waiting_trx_age: 00:00:12 +-- waiting_trx_rows_locked: 0 +-- waiting_trx_rows_modified: 0 +-- waiting_pid: 3 +-- waiting_query: UPDATE t1 SET val = val + 1 WHERE id = 2 +-- waiting_lock_id: 867158:2363:3:3 +-- waiting_lock_mode: X +-- blocking_trx_id: 867157 +-- blocking_pid: 4 +-- blocking_query: UPDATE t1 SET val = val + 1 + SLEEP(10) WHERE id = 2 +-- blocking_lock_id: 867157:2363:3:3 +-- blocking_lock_mode: X +-- blocking_trx_started: 2014-11-11 13:39:11 +-- blocking_trx_age: 00:00:16 +-- blocking_trx_rows_locked: 1 +-- blocking_trx_rows_modified: 1 +-- sql_kill_blocking_query: KILL QUERY 4 +-- sql_kill_blocking_connection: KILL 4 +-- 1 row in set (0.01 sec) +-- +DELIMITER $$ +BEGIN NOT ATOMIC + DECLARE EXIT HANDLER FOR SQLEXCEPTION + BEGIN + END; +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW innodb_lock_waits ( + wait_started, + wait_age, + wait_age_secs, + locked_table, + locked_index, + locked_type, + waiting_trx_id, + waiting_trx_started, + waiting_trx_age, + waiting_trx_rows_locked, + waiting_trx_rows_modified, + waiting_pid, + waiting_query, + waiting_lock_id, + waiting_lock_mode, + blocking_trx_id, + blocking_pid, + blocking_query, + blocking_lock_id, + blocking_lock_mode, + blocking_trx_started, + blocking_trx_age, + blocking_trx_rows_locked, + blocking_trx_rows_modified, + sql_kill_blocking_query, + sql_kill_blocking_connection +) AS +SELECT r.trx_wait_started AS wait_started, + TIMEDIFF(NOW(), r.trx_wait_started) AS wait_age, + TIMESTAMPDIFF(SECOND, r.trx_wait_started, NOW()) AS wait_age_secs, + rl.lock_table AS locked_table, + rl.lock_index AS locked_index, + rl.lock_type AS locked_type, + r.trx_id AS waiting_trx_id, + r.trx_started as waiting_trx_started, + TIMEDIFF(NOW(), r.trx_started) AS waiting_trx_age, + r.trx_rows_locked AS waiting_trx_rows_locked, + r.trx_rows_modified AS waiting_trx_rows_modified, + r.trx_mysql_thread_id AS waiting_pid, + sys.format_statement(r.trx_query) AS waiting_query, + rl.lock_id AS waiting_lock_id, + rl.lock_mode AS waiting_lock_mode, + b.trx_id AS blocking_trx_id, + b.trx_mysql_thread_id AS blocking_pid, + sys.format_statement(b.trx_query) AS blocking_query, + bl.lock_id AS blocking_lock_id, + bl.lock_mode AS blocking_lock_mode, + b.trx_started AS blocking_trx_started, + TIMEDIFF(NOW(), b.trx_started) AS blocking_trx_age, + b.trx_rows_locked AS blocking_trx_rows_locked, + b.trx_rows_modified AS blocking_trx_rows_modified, + CONCAT('KILL QUERY ', b.trx_mysql_thread_id) AS sql_kill_blocking_query, + CONCAT('KILL ', b.trx_mysql_thread_id) AS sql_kill_blocking_connection + FROM information_schema.innodb_lock_waits w + INNER JOIN information_schema.innodb_trx b ON b.trx_id = w.blocking_trx_id + INNER JOIN information_schema.innodb_trx r ON r.trx_id = w.requesting_trx_id + INNER JOIN information_schema.innodb_locks bl ON bl.lock_id = w.blocking_lock_id + INNER JOIN information_schema.innodb_locks rl ON rl.lock_id = w.requested_lock_id + ORDER BY r.trx_wait_started; + END$$ +DELIMITER ; diff --git a/scripts/sys_schema/views/i_s/schema_auto_increment_columns.sql b/scripts/sys_schema/views/i_s/schema_auto_increment_columns.sql new file mode 100644 index 00000000..98c95695 --- /dev/null +++ b/scripts/sys_schema/views/i_s/schema_auto_increment_columns.sql @@ -0,0 +1,66 @@ + +-- +-- View: schema_auto_increment_columns +-- +-- Present current auto_increment usage/capacity in all tables. +-- +-- mysql> select * from schema_auto_increment_columns limit 5; +-- +-------------------+-------------------+-------------+-----------+-------------+-----------+-------------+---------------------+----------------+----------------------+ +-- | table_schema | table_name | column_name | data_type | column_type | is_signed | is_unsigned | max_value | auto_increment | auto_increment_ratio | +-- +-------------------+-------------------+-------------+-----------+-------------+-----------+-------------+---------------------+----------------+----------------------+ +-- | test | t1 | i | tinyint | tinyint(4) | 1 | 0 | 127 | 34 | 0.2677 | +-- | mem__advisor_text | template_meta | hib_id | int | int(11) | 1 | 0 | 2147483647 | 516 | 0.0000 | +-- | mem__advisors | advisor_schedules | schedule_id | int | int(11) | 1 | 0 | 2147483647 | 249 | 0.0000 | +-- | mem__advisors | app_identity_path | hib_id | int | int(11) | 1 | 0 | 2147483647 | 251 | 0.0000 | +-- | mem__bean_config | plists | id | bigint | bigint(20) | 1 | 0 | 9223372036854775807 | 1 | 0.0000 | +-- +-------------------+-------------------+-------------+-----------+-------------+-----------+-------------+---------------------+----------------+----------------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW schema_auto_increment_columns ( + table_schema, + table_name, + column_name, + data_type, + column_type, + is_signed, + is_unsigned, + max_value, + auto_increment, + auto_increment_ratio +) AS +SELECT TABLE_SCHEMA, + TABLE_NAME, + COLUMN_NAME, + DATA_TYPE, + COLUMN_TYPE, + (LOCATE('unsigned', COLUMN_TYPE) = 0) AS is_signed, + (LOCATE('unsigned', COLUMN_TYPE) > 0) AS is_unsigned, + ( + CASE DATA_TYPE + WHEN 'tinyint' THEN 255 + WHEN 'smallint' THEN 65535 + WHEN 'mediumint' THEN 16777215 + WHEN 'int' THEN 4294967295 + WHEN 'bigint' THEN 18446744073709551615 + END >> IF(LOCATE('unsigned', COLUMN_TYPE) > 0, 0, 1) + ) AS max_value, + AUTO_INCREMENT, + AUTO_INCREMENT / ( + CASE DATA_TYPE + WHEN 'tinyint' THEN 255 + WHEN 'smallint' THEN 65535 + WHEN 'mediumint' THEN 16777215 + WHEN 'int' THEN 4294967295 + WHEN 'bigint' THEN 18446744073709551615 + END >> IF(LOCATE('unsigned', COLUMN_TYPE) > 0, 0, 1) + ) AS auto_increment_ratio + FROM INFORMATION_SCHEMA.COLUMNS + INNER JOIN INFORMATION_SCHEMA.TABLES USING (TABLE_SCHEMA, TABLE_NAME) + WHERE TABLE_SCHEMA NOT IN ('mysql', 'sys', 'INFORMATION_SCHEMA', 'performance_schema') + AND TABLE_TYPE='BASE TABLE' + AND EXTRA='auto_increment' + ORDER BY auto_increment_ratio DESC, max_value; diff --git a/scripts/sys_schema/views/i_s/schema_object_overview.sql b/scripts/sys_schema/views/i_s/schema_object_overview.sql new file mode 100644 index 00000000..9da11254 --- /dev/null +++ b/scripts/sys_schema/views/i_s/schema_object_overview.sql @@ -0,0 +1,58 @@ +-- 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: schema_object_overview +-- +-- Shows an overview of the types of objects within each schema +-- +-- Note: On instances with a large number of objects, this could take +-- some time to execute, and is not recommended. +-- +-- mysql> select * from schema_object_overview; +-- +---------------------------------+---------------+-------+ +-- | db | object_type | count | +-- +---------------------------------+---------------+-------+ +-- | information_schema | SYSTEM VIEW | 59 | +-- | mem30_test__instruments | BASE TABLE | 1 | +-- | mem30_test__instruments | INDEX (BTREE) | 2 | +-- | mem30_test__test | BASE TABLE | 9 | +-- | mem30_test__test | INDEX (BTREE) | 19 | +-- ... +-- | sys | FUNCTION | 8 | +-- | sys | PROCEDURE | 16 | +-- | sys | VIEW | 59 | +-- +---------------------------------+---------------+-------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW schema_object_overview ( + db, + object_type, + count +) AS +SELECT ROUTINE_SCHEMA AS db, ROUTINE_TYPE AS object_type, COUNT(*) AS count FROM information_schema.routines GROUP BY ROUTINE_SCHEMA, ROUTINE_TYPE + UNION +SELECT TABLE_SCHEMA, TABLE_TYPE, COUNT(*) FROM information_schema.tables GROUP BY TABLE_SCHEMA, TABLE_TYPE + UNION +SELECT TABLE_SCHEMA, CONCAT('INDEX (', INDEX_TYPE, ')'), COUNT(*) FROM information_schema.statistics GROUP BY TABLE_SCHEMA, INDEX_TYPE + UNION +SELECT TRIGGER_SCHEMA, 'TRIGGER', COUNT(*) FROM information_schema.triggers GROUP BY TRIGGER_SCHEMA + UNION +SELECT EVENT_SCHEMA, 'EVENT', COUNT(*) FROM information_schema.events GROUP BY EVENT_SCHEMA +ORDER BY DB, OBJECT_TYPE; diff --git a/scripts/sys_schema/views/i_s/schema_redundant_indexes.sql b/scripts/sys_schema/views/i_s/schema_redundant_indexes.sql new file mode 100644 index 00000000..8ad8bb82 --- /dev/null +++ b/scripts/sys_schema/views/i_s/schema_redundant_indexes.sql @@ -0,0 +1,92 @@ +-- +-- View: schema_redundant_keys +-- +-- Shows indexes which are made redundant (or duplicate) by other (dominant) keys. +-- +-- mysql> select * from sys.schema_redundant_indexes\G +-- *************************** 1. row *************************** +-- table_schema: test +-- table_name: rkey +-- redundant_index_name: j +-- redundant_index_columns: j +-- redundant_index_non_unique: 1 +-- dominant_index_name: j_2 +-- dominant_index_columns: j,k +-- dominant_index_non_unique: 1 +-- subpart_exists: 0 +-- sql_drop_index: ALTER TABLE `test`.`rkey` DROP INDEX `j` +-- 1 row in set (0.20 sec) +-- +-- mysql> SHOW CREATE TABLE test.rkey\G +-- *************************** 1. row *************************** +-- Table: rkey +-- Create Table: CREATE TABLE `rkey` ( +-- `i` int(11) NOT NULL, +-- `j` int(11) DEFAULT NULL, +-- `k` int(11) DEFAULT NULL, +-- PRIMARY KEY (`i`), +-- KEY `j` (`j`), +-- KEY `j_2` (`j`,`k`) +-- ) ENGINE=InnoDB DEFAULT CHARSET=latin1 +-- 1 row in set (0.06 sec) +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW schema_redundant_indexes ( + table_schema, + table_name, + redundant_index_name, + redundant_index_columns, + redundant_index_non_unique, + dominant_index_name, + dominant_index_columns, + dominant_index_non_unique, + subpart_exists, + sql_drop_index +) AS + SELECT + redundant_keys.table_schema, + redundant_keys.table_name, + redundant_keys.index_name AS redundant_index_name, + redundant_keys.index_columns AS redundant_index_columns, + redundant_keys.non_unique AS redundant_index_non_unique, + dominant_keys.index_name AS dominant_index_name, + dominant_keys.index_columns AS dominant_index_columns, + dominant_keys.non_unique AS dominant_index_non_unique, + IF(redundant_keys.subpart_exists OR dominant_keys.subpart_exists, 1 ,0) AS subpart_exists, + CONCAT( + 'ALTER TABLE `', redundant_keys.table_schema, '`.`', redundant_keys.table_name, '` DROP INDEX `', redundant_keys.index_name, '`' + ) AS sql_drop_index + FROM + x$schema_flattened_keys AS redundant_keys + INNER JOIN x$schema_flattened_keys AS dominant_keys + USING (TABLE_SCHEMA, TABLE_NAME) + WHERE + redundant_keys.index_name != dominant_keys.index_name + AND ( + ( + /* Identical columns */ + (redundant_keys.index_columns = dominant_keys.index_columns) + AND ( + (redundant_keys.non_unique > dominant_keys.non_unique) + OR (redundant_keys.non_unique = dominant_keys.non_unique + AND IF(redundant_keys.index_name='PRIMARY', '', redundant_keys.index_name) > IF(dominant_keys.index_name='PRIMARY', '', dominant_keys.index_name) + ) + ) + ) + OR + ( + /* Non-unique prefix columns */ + LOCATE(CONCAT(redundant_keys.index_columns, ','), dominant_keys.index_columns) = 1 + AND redundant_keys.non_unique = 1 + ) + OR + ( + /* Unique prefix columns */ + LOCATE(CONCAT(dominant_keys.index_columns, ','), redundant_keys.index_columns) = 1 + AND dominant_keys.non_unique = 0 + ) + ); diff --git a/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_schema.sql b/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_schema.sql new file mode 100644 index 00000000..6637f509 --- /dev/null +++ b/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_schema.sql @@ -0,0 +1,62 @@ +-- Copyright (c) 2014, 2016, 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: x$innodb_buffer_stats_by_schema +-- +-- Summarizes the output of the INFORMATION_SCHEMA.INNODB_BUFFER_PAGE +-- table, aggregating by schema +-- +-- mysql> select * from x$innodb_buffer_stats_by_schema; +-- +--------------------------+-----------+--------+-------+--------------+-----------+-------------+ +-- | object_schema | allocated | data | pages | pages_hashed | pages_old | rows_cached | +-- +--------------------------+-----------+--------+-------+--------------+-----------+-------------+ +-- | mem30_trunk__instruments | 1769472 | 522272 | 108 | 108 | 108 | 3885 | +-- | InnoDB System | 704512 | 360054 | 43 | 43 | 43 | 862 | +-- | mem30_trunk__events | 81920 | 22125 | 5 | 5 | 5 | 229 | +-- +--------------------------+-----------+--------+-------+--------------+-----------+-------------+ +-- + +DELIMITER $$ +BEGIN NOT ATOMIC + DECLARE EXIT HANDLER FOR SQLEXCEPTION + BEGIN + END; +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$innodb_buffer_stats_by_schema ( + object_schema, + allocated, + data, + pages, + pages_hashed, + pages_old, + rows_cached +) AS +SELECT IF(LOCATE('.', ibp.table_name) = 0, 'InnoDB System', REPLACE(SUBSTRING_INDEX(ibp.table_name, '.', 1), '`', '')) AS object_schema, + SUM(IF(ibp.compressed_size = 0, 16384, compressed_size)) AS allocated, + SUM(ibp.data_size) AS data, + COUNT(ibp.page_number) AS pages, + COUNT(IF(ibp.is_hashed, 1, NULL)) AS pages_hashed, + COUNT(IF(ibp.is_old, 1, NULL)) AS pages_old, + ROUND(IFNULL(SUM(ibp.number_records)/NULLIF(COUNT(DISTINCT ibp.index_name), 0), 0)) AS rows_cached + FROM information_schema.innodb_buffer_page ibp + WHERE table_name IS NOT NULL + GROUP BY object_schema + ORDER BY SUM(IF(ibp.compressed_size = 0, 16384, compressed_size)) DESC; +END$$ +DELIMITER ; diff --git a/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_table.sql b/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_table.sql new file mode 100644 index 00000000..39d19b05 --- /dev/null +++ b/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_table.sql @@ -0,0 +1,66 @@ +-- Copyright (c) 2014, 2016, 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: x$innodb_buffer_stats_by_table +-- +-- Summarizes the output of the INFORMATION_SCHEMA.INNODB_BUFFER_PAGE +-- table, aggregating by schema and table name +-- +-- mysql> select * from x$innodb_buffer_stats_by_table; +-- +--------------------------+------------------------------------+-----------+--------+-------+--------------+-----------+-------------+ +-- | object_schema | object_name | allocated | data | pages | pages_hashed | pages_old | rows_cached | +-- +--------------------------+------------------------------------+-----------+--------+-------+--------------+-----------+-------------+ +-- | InnoDB System | SYS_COLUMNS | 131072 | 101350 | 8 | 8 | 8 | 1532 | +-- | InnoDB System | SYS_FOREIGN | 131072 | 56808 | 8 | 8 | 8 | 172 | +-- | InnoDB System | SYS_TABLES | 131072 | 57529 | 8 | 8 | 8 | 365 | +-- | InnoDB System | SYS_INDEXES | 114688 | 77984 | 7 | 7 | 7 | 1046 | +-- | mem30_trunk__instruments | agentlatencytime | 98304 | 29517 | 6 | 6 | 6 | 252 | +-- | mem30_trunk__instruments | binlogspaceusagedata | 98304 | 23076 | 6 | 6 | 6 | 196 | +-- | mem30_trunk__instruments | connectionsdata | 98304 | 37563 | 6 | 6 | 6 | 276 | +-- ... +-- +--------------------------+------------------------------------+-----------+--------+-------+--------------+-----------+-------------+ +-- +DELIMITER $$ +BEGIN NOT ATOMIC +DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN END; +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$innodb_buffer_stats_by_table ( + object_schema, + object_name, + allocated, + data, + pages, + pages_hashed, + pages_old, + rows_cached +) AS +SELECT IF(LOCATE('.', ibp.table_name) = 0, 'InnoDB System', REPLACE(SUBSTRING_INDEX(ibp.table_name, '.', 1), '`', '')) AS object_schema, + REPLACE(SUBSTRING_INDEX(ibp.table_name, '.', -1), '`', '') AS object_name, + SUM(IF(ibp.compressed_size = 0, 16384, compressed_size)) AS allocated, + SUM(ibp.data_size) AS data, + COUNT(ibp.page_number) AS pages, + COUNT(IF(ibp.is_hashed, 1, NULL)) AS pages_hashed, + COUNT(IF(ibp.is_old, 1, NULL)) AS pages_old, + ROUND(IFNULL(SUM(ibp.number_records)/NULLIF(COUNT(DISTINCT ibp.index_name), 0), 0)) AS rows_cached + FROM information_schema.innodb_buffer_page ibp + WHERE table_name IS NOT NULL + GROUP BY object_schema, object_name + ORDER BY SUM(IF(ibp.compressed_size = 0, 16384, compressed_size)) DESC; +END$$ +DELIMITER ;
\ No newline at end of file diff --git a/scripts/sys_schema/views/i_s/x_innodb_lock_waits.sql b/scripts/sys_schema/views/i_s/x_innodb_lock_waits.sql new file mode 100644 index 00000000..a36bc4d7 --- /dev/null +++ b/scripts/sys_schema/views/i_s/x_innodb_lock_waits.sql @@ -0,0 +1,124 @@ +-- 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: x$innodb_lock_waits +-- +-- Give a snapshot of which InnoDB locks transactions are waiting for. +-- The lock waits are ordered by the age of the lock descending. +-- +-- Versions: 5.1+ (5.1 requires InnoDB Plugin with I_S tables) +-- +-- mysql> SELECT * FROM x$innodb_lock_waits\G +-- *************************** 1. row *************************** +-- wait_started: 2014-11-11 13:39:20 +-- wait_age: 00:00:07 +-- wait_age_secs: 7 +-- locked_table: `db1`.`t1` +-- locked_index: PRIMARY +-- locked_type: RECORD +-- waiting_trx_id: 867158 +-- waiting_trx_started: 2014-11-11 13:39:15 +-- waiting_trx_age: 00:00:12 +-- waiting_trx_rows_locked: 0 +-- waiting_trx_rows_modified: 0 +-- waiting_pid: 3 +-- waiting_query: UPDATE t1 SET val = val + 1 WHERE id = 2 +-- waiting_lock_id: 867158:2363:3:3 +-- waiting_lock_mode: X +-- blocking_trx_id: 867157 +-- blocking_pid: 4 +-- blocking_query: UPDATE t1 SET val = val + 1 + SLEEP(10) WHERE id = 2 +-- blocking_lock_id: 867157:2363:3:3 +-- blocking_lock_mode: X +-- blocking_trx_started: 2014-11-11 13:39:11 +-- blocking_trx_age: 00:00:16 +-- blocking_trx_rows_locked: 1 +-- blocking_trx_rows_modified: 1 +-- sql_kill_blocking_query: KILL QUERY 4 +-- sql_kill_blocking_connection: KILL 4 +-- 1 row in set (0.01 sec) +-- + +DELIMITER $$ +BEGIN NOT ATOMIC +DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN END; + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$innodb_lock_waits ( + wait_started, + wait_age, + wait_age_secs, + locked_table, + locked_index, + locked_type, + waiting_trx_id, + waiting_trx_started, + waiting_trx_age, + waiting_trx_rows_locked, + waiting_trx_rows_modified, + waiting_pid, + waiting_query, + waiting_lock_id, + waiting_lock_mode, + blocking_trx_id, + blocking_pid, + blocking_query, + blocking_lock_id, + blocking_lock_mode, + blocking_trx_started, + blocking_trx_age, + blocking_trx_rows_locked, + blocking_trx_rows_modified, + sql_kill_blocking_query, + sql_kill_blocking_connection +) AS +SELECT r.trx_wait_started AS wait_started, + TIMEDIFF(NOW(), r.trx_wait_started) AS wait_age, + TIMESTAMPDIFF(SECOND, r.trx_wait_started, NOW()) AS wait_age_secs, + rl.lock_table AS locked_table, + rl.lock_index AS locked_index, + rl.lock_type AS locked_type, + r.trx_id AS waiting_trx_id, + r.trx_started as waiting_trx_started, + TIMEDIFF(NOW(), r.trx_started) AS waiting_trx_age, + r.trx_rows_locked AS waiting_trx_rows_locked, + r.trx_rows_modified AS waiting_trx_rows_modified, + r.trx_mysql_thread_id AS waiting_pid, + r.trx_query AS waiting_query, + rl.lock_id AS waiting_lock_id, + rl.lock_mode AS waiting_lock_mode, + b.trx_id AS blocking_trx_id, + b.trx_mysql_thread_id AS blocking_pid, + b.trx_query AS blocking_query, + bl.lock_id AS blocking_lock_id, + bl.lock_mode AS blocking_lock_mode, + b.trx_started AS blocking_trx_started, + TIMEDIFF(NOW(), b.trx_started) AS blocking_trx_age, + b.trx_rows_locked AS blocking_trx_rows_locked, + b.trx_rows_modified AS blocking_trx_rows_modified, + CONCAT('KILL QUERY ', b.trx_mysql_thread_id) AS sql_kill_blocking_query, + CONCAT('KILL ', b.trx_mysql_thread_id) AS sql_kill_blocking_connection + FROM information_schema.innodb_lock_waits w + INNER JOIN information_schema.innodb_trx b ON b.trx_id = w.blocking_trx_id + INNER JOIN information_schema.innodb_trx r ON r.trx_id = w.requesting_trx_id + INNER JOIN information_schema.innodb_locks bl ON bl.lock_id = w.blocking_lock_id + INNER JOIN information_schema.innodb_locks rl ON rl.lock_id = w.requested_lock_id + ORDER BY r.trx_wait_started; +END$$ +DELIMITER ; diff --git a/scripts/sys_schema/views/i_s/x_schema_flattened_keys.sql b/scripts/sys_schema/views/i_s/x_schema_flattened_keys.sql new file mode 100644 index 00000000..35001158 --- /dev/null +++ b/scripts/sys_schema/views/i_s/x_schema_flattened_keys.sql @@ -0,0 +1,42 @@ +-- +-- View: x$schema_flattened_keys +-- +-- Helper view for the schema_redundant_keys view. +-- +-- mysql> select * from sys.x$schema_flattened_keys; +-- +---------------+---------------------+------------------------------+------------+----------------+-----------------+ +-- | table_schema | table_name | index_name | non_unique | subpart_exists | index_columns | +-- +---------------+---------------------+------------------------------+------------+----------------+-----------------+ +-- | mem__advisors | advisor_initialized | PRIMARY | 0 | 0 | advisorClassId | +-- | mem__advisors | advisor_schedules | advisorClassIdIdx | 1 | 0 | advisorClassId | +-- | mem__advisors | advisor_schedules | PRIMARY | 0 | 0 | schedule_id | +-- | mem__advisors | app_identity_path | FK_7xbq2i81hgo0xlvnb6rr77s21 | 1 | 0 | for_schedule_id | +-- | mem__advisors | app_identity_path | PRIMARY | 0 | 0 | hib_id | +-- ... +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$schema_flattened_keys ( + table_schema, + table_name, + index_name, + non_unique, + subpart_exists, + index_columns +) AS + SELECT + TABLE_SCHEMA, + TABLE_NAME, + INDEX_NAME, + MAX(NON_UNIQUE) AS non_unique, + MAX(IF(SUB_PART IS NULL, 0, 1)) AS subpart_exists, + GROUP_CONCAT(COLUMN_NAME ORDER BY SEQ_IN_INDEX) AS index_columns + FROM INFORMATION_SCHEMA.STATISTICS + WHERE + INDEX_TYPE='BTREE' + AND TABLE_SCHEMA NOT IN ('mysql', 'sys', 'INFORMATION_SCHEMA', 'PERFORMANCE_SCHEMA') + GROUP BY + TABLE_SCHEMA, TABLE_NAME, INDEX_NAME; diff --git a/scripts/sys_schema/views/p_s/host_summary.sql b/scripts/sys_schema/views/p_s/host_summary.sql new file mode 100644 index 00000000..080100a4 --- /dev/null +++ b/scripts/sys_schema/views/p_s/host_summary.sql @@ -0,0 +1,60 @@ +-- 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: host_summary +-- +-- Summarizes statement activity, file IO and connections by host. +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from host_summary; +-- +------+------------+-------------------+-----------------------+-------------+----------+-----------------+---------------------+-------------------+--------------+ +-- | host | statements | statement_latency | statement_avg_latency | table_scans | file_ios | file_io_latency | current_connections | total_connections | unique_users | +-- +------+------------+-------------------+-----------------------+-------------+----------+-----------------+---------------------+-------------------+--------------+ +-- | hal1 | 2924 | 00:03:59.53 | 81.92 ms | 82 | 54702 | 55.61 s | 1 | 1 | 1 | +-- +------+------------+-------------------+-----------------------+-------------+----------+-----------------+---------------------+-------------------+--------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW host_summary ( + host, + statements, + statement_latency, + statement_avg_latency, + table_scans, + file_ios, + file_io_latency, + current_connections, + total_connections, + unique_users +) AS +SELECT IF(accounts.host IS NULL, 'background', accounts.host) AS host, + SUM(stmt.total) AS statements, + sys.format_time(SUM(stmt.total_latency)) AS statement_latency, + sys.format_time(IFNULL(SUM(stmt.total_latency) / NULLIF(SUM(stmt.total), 0), 0)) AS statement_avg_latency, + SUM(stmt.full_scans) AS table_scans, + SUM(io.ios) AS file_ios, + sys.format_time(SUM(io.io_latency)) AS file_io_latency, + SUM(accounts.current_connections) AS current_connections, + SUM(accounts.total_connections) AS total_connections, + COUNT(DISTINCT accounts.user) AS unique_users + FROM performance_schema.accounts + LEFT JOIN sys.x$host_summary_by_statement_latency AS stmt ON accounts.host = stmt.host + LEFT JOIN sys.x$host_summary_by_file_io AS io ON accounts.host = io.host + GROUP BY IF(accounts.host IS NULL, 'background', accounts.host); diff --git a/scripts/sys_schema/views/p_s/host_summary_57.sql b/scripts/sys_schema/views/p_s/host_summary_57.sql new file mode 100644 index 00000000..cd0739f4 --- /dev/null +++ b/scripts/sys_schema/views/p_s/host_summary_57.sql @@ -0,0 +1,66 @@ +-- 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: host_summary +-- +-- Summarizes statement activity and connections by host +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from host_summary; +-- +------+------------+---------------+-------------+---------------------+-------------------+--------------+----------------+------------------------+ +-- | host | statements | total_latency | avg_latency | current_connections | total_connections | unique_users | current_memory | total_memory_allocated | +-- +------+------------+---------------+-------------+---------------------+-------------------+--------------+----------------+------------------------+ +-- | hal1 | 5663 | 00:01:47.14 | 18.92 ms | 1 | 1 | 1 | 1.41 MiB | 543.55 MiB | +-- | hal2 | 225 | 14.49 s | 64.40 ms | 1 | 1 | 1 | 707.60 KiB | 81.02 MiB | +-- +------+------------+---------------+-------------+---------------------+-------------------+--------------+----------------+------------------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW host_summary ( + host, + statements, + statement_latency, + statement_avg_latency, + table_scans, + file_ios, + file_io_latency, + current_connections, + total_connections, + unique_users, + current_memory, + total_memory_allocated +) AS +SELECT IF(accounts.host IS NULL, 'background', accounts.host) AS host, + SUM(stmt.total) AS statements, + sys.format_time(SUM(stmt.total_latency)) AS statement_latency, + sys.format_time(IFNULL(SUM(stmt.total_latency) / NULLIF(SUM(stmt.total), 0), 0)) AS statement_avg_latency, + SUM(stmt.full_scans) AS table_scans, + SUM(io.ios) AS file_ios, + sys.format_time(SUM(io.io_latency)) AS file_io_latency, + SUM(accounts.current_connections) AS current_connections, + SUM(accounts.total_connections) AS total_connections, + COUNT(DISTINCT user) AS unique_users, + sys.format_bytes(SUM(mem.current_allocated)) AS current_memory, + sys.format_bytes(SUM(mem.total_allocated)) AS total_memory_allocated + FROM performance_schema.accounts + JOIN sys.x$host_summary_by_statement_latency AS stmt ON accounts.host = stmt.host + JOIN sys.x$host_summary_by_file_io AS io ON accounts.host = io.host + JOIN sys.x$memory_by_host_by_current_bytes mem ON accounts.host = mem.host + GROUP BY IF(accounts.host IS NULL, 'background', accounts.host); diff --git a/scripts/sys_schema/views/p_s/host_summary_by_file_io.sql b/scripts/sys_schema/views/p_s/host_summary_by_file_io.sql new file mode 100644 index 00000000..e1fbf2ea --- /dev/null +++ b/scripts/sys_schema/views/p_s/host_summary_by_file_io.sql @@ -0,0 +1,47 @@ +-- 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: host_summary_by_file_io +-- +-- Summarizes file IO totals per host. +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from host_summary_by_file_io; +-- +------------+-------+------------+ +-- | host | ios | io_latency | +-- +------------+-------+------------+ +-- | hal1 | 26457 | 21.58 s | +-- | hal2 | 1189 | 394.21 ms | +-- +------------+-------+------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW host_summary_by_file_io ( + host, + ios, + io_latency +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + SUM(count_star) AS ios, + sys.format_time(SUM(sum_timer_wait)) AS io_latency + FROM performance_schema.events_waits_summary_by_host_by_event_name + WHERE event_name LIKE 'wait/io/file/%' + GROUP BY IF(host IS NULL, 'background', host) + ORDER BY SUM(sum_timer_wait) DESC; diff --git a/scripts/sys_schema/views/p_s/host_summary_by_file_io_type.sql b/scripts/sys_schema/views/p_s/host_summary_by_file_io_type.sql new file mode 100644 index 00000000..58567e3f --- /dev/null +++ b/scripts/sys_schema/views/p_s/host_summary_by_file_io_type.sql @@ -0,0 +1,66 @@ +-- 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: host_summary_by_file_io_type +-- +-- Summarizes file IO by event type per host. +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from host_summary_by_file_io_type; +-- +------------+--------------------------------------+-------+---------------+-------------+ +-- | host | event_name | total | total_latency | max_latency | +-- +------------+--------------------------------------+-------+---------------+-------------+ +-- | hal1 | wait/io/file/sql/FRM | 871 | 168.15 ms | 18.48 ms | +-- | hal1 | wait/io/file/innodb/innodb_data_file | 173 | 129.56 ms | 34.09 ms | +-- | hal1 | wait/io/file/innodb/innodb_log_file | 20 | 77.53 ms | 60.66 ms | +-- | hal1 | wait/io/file/myisam/dfile | 40 | 6.54 ms | 4.58 ms | +-- | hal1 | wait/io/file/mysys/charset | 3 | 4.79 ms | 4.71 ms | +-- | hal1 | wait/io/file/myisam/kfile | 67 | 4.38 ms | 300.04 us | +-- | hal1 | wait/io/file/sql/ERRMSG | 5 | 2.72 ms | 1.69 ms | +-- | hal1 | wait/io/file/sql/pid | 3 | 266.30 us | 185.47 us | +-- | hal1 | wait/io/file/sql/casetest | 5 | 246.81 us | 150.19 us | +-- | hal1 | wait/io/file/sql/global_ddl_log | 2 | 21.24 us | 18.59 us | +-- | hal2 | wait/io/file/sql/file_parser | 1422 | 4.80 s | 135.14 ms | +-- | hal2 | wait/io/file/sql/FRM | 865 | 85.82 ms | 9.81 ms | +-- | hal2 | wait/io/file/myisam/kfile | 1073 | 37.14 ms | 15.79 ms | +-- | hal2 | wait/io/file/myisam/dfile | 2991 | 25.53 ms | 5.25 ms | +-- | hal2 | wait/io/file/sql/dbopt | 20 | 1.07 ms | 153.07 us | +-- | hal2 | wait/io/file/sql/misc | 4 | 59.71 us | 33.75 us | +-- | hal2 | wait/io/file/archive/data | 1 | 13.91 us | 13.91 us | +-- +------------+--------------------------------------+-------+---------------+-------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW host_summary_by_file_io_type ( + host, + event_name, + total, + total_latency, + max_latency +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + event_name, + count_star AS total, + sys.format_time(sum_timer_wait) AS total_latency, + sys.format_time(max_timer_wait) AS max_latency + FROM performance_schema.events_waits_summary_by_host_by_event_name + WHERE event_name LIKE 'wait/io/file%' + AND count_star > 0 + ORDER BY IF(host IS NULL, 'background', host), sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/host_summary_by_stages.sql b/scripts/sys_schema/views/p_s/host_summary_by_stages.sql new file mode 100644 index 00000000..97e5a7ee --- /dev/null +++ b/scripts/sys_schema/views/p_s/host_summary_by_stages.sql @@ -0,0 +1,64 @@ +-- 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: host_summary_by_stages +-- +-- Summarizes stages by host, ordered by host and total latency per stage. +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from host_summary_by_stages; +-- +------+--------------------------------+-------+---------------+-------------+ +-- | host | event_name | total | total_latency | avg_latency | +-- +------+--------------------------------+-------+---------------+-------------+ +-- | hal | stage/sql/Opening tables | 889 | 1.97 ms | 2.22 us | +-- | hal | stage/sql/Creating sort index | 4 | 1.79 ms | 446.30 us | +-- | hal | stage/sql/init | 10 | 312.27 us | 31.23 us | +-- | hal | stage/sql/checking permissions | 10 | 300.62 us | 30.06 us | +-- | hal | stage/sql/freeing items | 5 | 85.89 us | 17.18 us | +-- | hal | stage/sql/statistics | 5 | 79.15 us | 15.83 us | +-- | hal | stage/sql/preparing | 5 | 69.12 us | 13.82 us | +-- | hal | stage/sql/optimizing | 5 | 53.11 us | 10.62 us | +-- | hal | stage/sql/Sending data | 5 | 44.66 us | 8.93 us | +-- | hal | stage/sql/closing tables | 5 | 37.54 us | 7.51 us | +-- | hal | stage/sql/System lock | 5 | 34.28 us | 6.86 us | +-- | hal | stage/sql/query end | 5 | 24.37 us | 4.87 us | +-- | hal | stage/sql/end | 5 | 8.60 us | 1.72 us | +-- | hal | stage/sql/Sorting result | 5 | 8.33 us | 1.67 us | +-- | hal | stage/sql/executing | 5 | 5.37 us | 1.07 us | +-- | hal | stage/sql/cleaning up | 5 | 4.60 us | 919.00 ns | +-- +------+--------------------------------+-------+---------------+-------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW host_summary_by_stages ( + host, + event_name, + total, + total_latency, + avg_latency +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + event_name, + count_star AS total, + sys.format_time(sum_timer_wait) AS total_latency, + sys.format_time(avg_timer_wait) AS avg_latency + FROM performance_schema.events_stages_summary_by_host_by_event_name + WHERE sum_timer_wait != 0 + ORDER BY IF(host IS NULL, 'background', host), sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/host_summary_by_statement_latency.sql b/scripts/sys_schema/views/p_s/host_summary_by_statement_latency.sql new file mode 100644 index 00000000..9eeb4c30 --- /dev/null +++ b/scripts/sys_schema/views/p_s/host_summary_by_statement_latency.sql @@ -0,0 +1,57 @@ +-- 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: host_summary_by_statement_latency +-- +-- Summarizes overall statement statistics by host. +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select-- from host_summary_by_statement_latency; +-- +------+-------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ +-- | host | total | total_latency | max_latency | lock_latency | rows_sent | rows_examined | rows_affected | full_scans | +-- +------+-------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ +-- | hal | 3381 | 00:02:09.13 | 1.48 s | 1.07 s | 1151 | 93947 | 150 | 91 | +-- +------+-------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW host_summary_by_statement_latency ( + host, + total, + total_latency, + max_latency, + lock_latency, + rows_sent, + rows_examined, + rows_affected, + full_scans +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + SUM(count_star) AS total, + sys.format_time(SUM(sum_timer_wait)) AS total_latency, + sys.format_time(MAX(max_timer_wait)) AS max_latency, + sys.format_time(SUM(sum_lock_time)) AS lock_latency, + SUM(sum_rows_sent) AS rows_sent, + SUM(sum_rows_examined) AS rows_examined, + SUM(sum_rows_affected) AS rows_affected, + SUM(sum_no_index_used) + SUM(sum_no_good_index_used) AS full_scans + FROM performance_schema.events_statements_summary_by_host_by_event_name + GROUP BY IF(host IS NULL, 'background', host) + ORDER BY SUM(sum_timer_wait) DESC; diff --git a/scripts/sys_schema/views/p_s/host_summary_by_statement_type.sql b/scripts/sys_schema/views/p_s/host_summary_by_statement_type.sql new file mode 100644 index 00000000..b529cd8c --- /dev/null +++ b/scripts/sys_schema/views/p_s/host_summary_by_statement_type.sql @@ -0,0 +1,64 @@ +-- 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: host_summary_by_statement_type +-- +-- Summarizes the types of statements executed by each host. +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from host_summary_by_statement_type; +-- +------+----------------------+--------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ +-- | host | statement | total | total_latency | max_latency | lock_latency | rows_sent | rows_examined | rows_affected | full_scans | +-- +------+----------------------+--------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ +-- | hal | create_view | 2063 | 00:05:04.20 | 463.58 ms | 1.42 s | 0 | 0 | 0 | 0 | +-- | hal | select | 174 | 40.87 s | 28.83 s | 858.13 ms | 5212 | 157022 | 0 | 82 | +-- | hal | stmt | 6645 | 15.31 s | 491.78 ms | 0 ps | 0 | 0 | 7951 | 0 | +-- | hal | call_procedure | 17 | 4.78 s | 1.02 s | 37.94 ms | 0 | 0 | 19 | 0 | +-- | hal | create_table | 19 | 3.04 s | 431.71 ms | 0 ps | 0 | 0 | 0 | 0 | +-- ... +-- +------+----------------------+--------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW host_summary_by_statement_type ( + host, + statement, + total, + total_latency, + max_latency, + lock_latency, + rows_sent, + rows_examined, + rows_affected, + full_scans +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + SUBSTRING_INDEX(event_name, '/', -1) AS statement, + count_star AS total, + sys.format_time(sum_timer_wait) AS total_latency, + sys.format_time(max_timer_wait) AS max_latency, + sys.format_time(sum_lock_time) AS lock_latency, + sum_rows_sent AS rows_sent, + sum_rows_examined AS rows_examined, + sum_rows_affected AS rows_affected, + sum_no_index_used + sum_no_good_index_used AS full_scans + FROM performance_schema.events_statements_summary_by_host_by_event_name + WHERE sum_timer_wait != 0 + ORDER BY IF(host IS NULL, 'background', host), sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/io_by_thread_by_latency.sql b/scripts/sys_schema/views/p_s/io_by_thread_by_latency.sql new file mode 100644 index 00000000..c5bf1c69 --- /dev/null +++ b/scripts/sys_schema/views/p_s/io_by_thread_by_latency.sql @@ -0,0 +1,70 @@ +-- 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: io_by_thread_by_latency +-- +-- Show the top IO consumers by thread, ordered by total latency +-- +-- mysql> select * from io_by_thread_by_latency; +-- +---------------------+-------+---------------+-------------+-------------+-------------+-----------+----------------+ +-- | user | total | total_latency | min_latency | avg_latency | max_latency | thread_id | processlist_id | +-- +---------------------+-------+---------------+-------------+-------------+-------------+-----------+----------------+ +-- | root@localhost | 11580 | 18.01 s | 429.78 ns | 1.12 ms | 181.07 ms | 25 | 6 | +-- | main | 1358 | 1.31 s | 475.02 ns | 2.27 ms | 350.70 ms | 1 | NULL | +-- | page_cleaner_thread | 654 | 147.44 ms | 588.12 ns | 225.44 us | 46.41 ms | 18 | NULL | +-- | io_write_thread | 131 | 107.75 ms | 8.60 us | 822.55 us | 27.69 ms | 8 | NULL | +-- | io_write_thread | 46 | 47.07 ms | 10.64 us | 1.02 ms | 16.90 ms | 9 | NULL | +-- | io_write_thread | 71 | 46.99 ms | 9.11 us | 661.81 us | 17.04 ms | 11 | NULL | +-- | io_log_thread | 20 | 21.01 ms | 14.25 us | 1.05 ms | 7.08 ms | 3 | NULL | +-- | srv_master_thread | 13 | 17.60 ms | 8.49 us | 1.35 ms | 9.99 ms | 16 | NULL | +-- | srv_purge_thread | 4 | 1.81 ms | 34.31 us | 452.45 us | 1.02 ms | 17 | NULL | +-- | io_write_thread | 19 | 951.39 us | 9.75 us | 50.07 us | 297.47 us | 10 | NULL | +-- | signal_handler | 3 | 218.03 us | 21.64 us | 72.68 us | 154.84 us | 19 | NULL | +-- +---------------------+-------+---------------+-------------+-------------+-------------+-----------+----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW io_by_thread_by_latency ( + user, + total, + total_latency, + min_latency, + avg_latency, + max_latency, + thread_id, + processlist_id +) +AS +SELECT IF(processlist_id IS NULL, + SUBSTRING_INDEX(name, '/', -1), + CONCAT(processlist_user, '@', processlist_host) + ) user, + SUM(count_star) total, + sys.format_time(SUM(sum_timer_wait)) total_latency, + sys.format_time(MIN(min_timer_wait)) min_latency, + sys.format_time(AVG(avg_timer_wait)) avg_latency, + sys.format_time(MAX(max_timer_wait)) max_latency, + thread_id, + processlist_id + FROM performance_schema.events_waits_summary_by_thread_by_event_name + LEFT JOIN performance_schema.threads USING (thread_id) + WHERE event_name LIKE 'wait/io/file/%' + AND sum_timer_wait > 0 + GROUP BY thread_id, processlist_id, user + ORDER BY SUM(sum_timer_wait) DESC; diff --git a/scripts/sys_schema/views/p_s/io_global_by_file_by_bytes.sql b/scripts/sys_schema/views/p_s/io_global_by_file_by_bytes.sql new file mode 100644 index 00000000..cca00495 --- /dev/null +++ b/scripts/sys_schema/views/p_s/io_global_by_file_by_bytes.sql @@ -0,0 +1,58 @@ +-- 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: io_global_by_file_by_bytes +-- +-- Shows the top global IO consumers by bytes usage by file. +-- +-- mysql> SELECT * FROM io_global_by_file_by_bytes LIMIT 5; +-- +--------------------------------------------+------------+------------+-----------+-------------+---------------+-----------+------------+-----------+ +-- | file | count_read | total_read | avg_read | count_write | total_written | avg_write | total | write_pct | +-- +--------------------------------------------+------------+------------+-----------+-------------+---------------+-----------+------------+-----------+ +-- | @@datadir/ibdata1 | 147 | 4.27 MiB | 29.71 KiB | 3 | 48.00 KiB | 16.00 KiB | 4.31 MiB | 1.09 | +-- | @@datadir/mysql/proc.MYD | 347 | 85.35 KiB | 252 bytes | 111 | 19.08 KiB | 176 bytes | 104.43 KiB | 18.27 | +-- | @@datadir/ib_logfile0 | 6 | 68.00 KiB | 11.33 KiB | 8 | 4.00 KiB | 512 bytes | 72.00 KiB | 5.56 | +-- | /opt/mysql/5.5.33/share/english/errmsg.sys | 3 | 43.68 KiB | 14.56 KiB | 0 | 0 bytes | 0 bytes | 43.68 KiB | 0.00 | +-- | /opt/mysql/5.5.33/share/charsets/Index.xml | 1 | 17.89 KiB | 17.89 KiB | 0 | 0 bytes | 0 bytes | 17.89 KiB | 0.00 | +-- +--------------------------------------------+------------+------------+-----------+-------------+---------------+-----------+------------+-----------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW io_global_by_file_by_bytes ( + file, + count_read, + total_read, + avg_read, + count_write, + total_written, + avg_write, + total, + write_pct +) AS +SELECT sys.format_path(file_name) AS file, + count_read, + sys.format_bytes(sum_number_of_bytes_read) AS total_read, + sys.format_bytes(IFNULL(sum_number_of_bytes_read / NULLIF(count_read, 0), 0)) AS avg_read, + count_write, + sys.format_bytes(sum_number_of_bytes_write) AS total_written, + sys.format_bytes(IFNULL(sum_number_of_bytes_write / NULLIF(count_write, 0), 0.00)) AS avg_write, + sys.format_bytes(sum_number_of_bytes_read + sum_number_of_bytes_write) AS total, + IFNULL(ROUND(100-((sum_number_of_bytes_read/ NULLIF((sum_number_of_bytes_read+sum_number_of_bytes_write), 0))*100), 2), 0.00) AS write_pct + FROM performance_schema.file_summary_by_instance + ORDER BY sum_number_of_bytes_read + sum_number_of_bytes_write DESC; diff --git a/scripts/sys_schema/views/p_s/io_global_by_file_by_latency.sql b/scripts/sys_schema/views/p_s/io_global_by_file_by_latency.sql new file mode 100644 index 00000000..97b0aae9 --- /dev/null +++ b/scripts/sys_schema/views/p_s/io_global_by_file_by_latency.sql @@ -0,0 +1,58 @@ +-- 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: io_global_by_file_by_latency +-- +-- Shows the top global IO consumers by latency by file. +-- +-- mysql> select * from io_global_by_file_by_latency limit 5; +-- +-----------------------------------------------------------+-------+---------------+------------+--------------+-------------+---------------+------------+--------------+ +-- | file | total | total_latency | count_read | read_latency | count_write | write_latency | count_misc | misc_latency | +-- +-----------------------------------------------------------+-------+---------------+------------+--------------+-------------+---------------+------------+--------------+ +-- | @@datadir/sys/wait_classes_global_by_avg_latency_raw.frm~ | 24 | 451.99 ms | 0 | 0 ps | 4 | 108.07 us | 20 | 451.88 ms | +-- | @@datadir/sys/innodb_buffer_stats_by_schema_raw.frm~ | 24 | 379.84 ms | 0 | 0 ps | 4 | 108.88 us | 20 | 379.73 ms | +-- | @@datadir/sys/io_by_thread_by_latency_raw.frm~ | 24 | 379.46 ms | 0 | 0 ps | 4 | 101.37 us | 20 | 379.36 ms | +-- | @@datadir/ibtmp1 | 53 | 373.45 ms | 0 | 0 ps | 48 | 246.08 ms | 5 | 127.37 ms | +-- | @@datadir/sys/statement_analysis_raw.frm~ | 24 | 353.14 ms | 0 | 0 ps | 4 | 94.96 us | 20 | 353.04 ms | +-- +-----------------------------------------------------------+-------+---------------+------------+--------------+-------------+---------------+------------+--------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW io_global_by_file_by_latency ( + file, + total, + total_latency, + count_read, + read_latency, + count_write, + write_latency, + count_misc, + misc_latency +) AS +SELECT sys.format_path(file_name) AS file, + count_star AS total, + sys.format_time(sum_timer_wait) AS total_latency, + count_read, + sys.format_time(sum_timer_read) AS read_latency, + count_write, + sys.format_time(sum_timer_write) AS write_latency, + count_misc, + sys.format_time(sum_timer_misc) AS misc_latency + FROM performance_schema.file_summary_by_instance + ORDER BY sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/io_global_by_wait_by_bytes.sql b/scripts/sys_schema/views/p_s/io_global_by_wait_by_bytes.sql new file mode 100644 index 00000000..edf6b994 --- /dev/null +++ b/scripts/sys_schema/views/p_s/io_global_by_wait_by_bytes.sql @@ -0,0 +1,79 @@ +-- 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: io_global_by_wait_by_bytes +-- +-- Shows the top global IO consumer classes by bytes usage. +-- +-- mysql> select * from io_global_by_wait_by_bytes; +-- +--------------------+--------+---------------+-------------+-------------+-------------+------------+------------+-----------+-------------+---------------+-------------+-----------------+ +-- | event_name | total | total_latency | min_latency | avg_latency | max_latency | count_read | total_read | avg_read | count_write | total_written | avg_written | total_requested | +-- +--------------------+--------+---------------+-------------+-------------+-------------+------------+------------+-----------+-------------+---------------+-------------+-----------------+ +-- | myisam/dfile | 163681 | 983.13 ms | 379.08 ns | 6.01 us | 22.06 ms | 68737 | 127.31 MiB | 1.90 KiB | 1012221 | 121.52 MiB | 126 bytes | 248.83 MiB | +-- | myisam/kfile | 1775 | 375.13 ms | 1.02 us | 211.34 us | 35.15 ms | 54066 | 9.97 MiB | 193 bytes | 428257 | 12.40 MiB | 30 bytes | 22.37 MiB | +-- | sql/FRM | 57889 | 8.40 s | 19.44 ns | 145.05 us | 336.71 ms | 8009 | 2.60 MiB | 341 bytes | 14675 | 2.91 MiB | 208 bytes | 5.51 MiB | +-- | sql/global_ddl_log | 164 | 75.96 ms | 5.72 us | 463.19 us | 7.43 ms | 20 | 80.00 KiB | 4.00 KiB | 76 | 304.00 KiB | 4.00 KiB | 384.00 KiB | +-- | sql/file_parser | 419 | 601.37 ms | 1.96 us | 1.44 ms | 37.14 ms | 66 | 42.01 KiB | 652 bytes | 64 | 226.98 KiB | 3.55 KiB | 268.99 KiB | +-- | sql/binlog | 190 | 6.79 s | 1.56 us | 35.76 ms | 4.21 s | 52 | 60.54 KiB | 1.16 KiB | 0 | 0 bytes | 0 bytes | 60.54 KiB | +-- | sql/ERRMSG | 5 | 2.03 s | 8.61 us | 405.40 ms | 2.03 s | 3 | 51.82 KiB | 17.27 KiB | 0 | 0 bytes | 0 bytes | 51.82 KiB | +-- | mysys/charset | 3 | 196.52 us | 17.61 us | 65.51 us | 137.33 us | 1 | 17.83 KiB | 17.83 KiB | 0 | 0 bytes | 0 bytes | 17.83 KiB | +-- | sql/partition | 81 | 18.87 ms | 888.08 ns | 232.92 us | 4.67 ms | 66 | 2.75 KiB | 43 bytes | 8 | 288 bytes | 36 bytes | 3.04 KiB | +-- | sql/dbopt | 329166 | 26.95 s | 2.06 us | 81.89 us | 178.71 ms | 0 | 0 bytes | 0 bytes | 9 | 585 bytes | 65 bytes | 585 bytes | +-- | sql/relaylog | 7 | 1.18 ms | 838.84 ns | 168.30 us | 892.70 us | 0 | 0 bytes | 0 bytes | 1 | 120 bytes | 120 bytes | 120 bytes | +-- | mysys/cnf | 5 | 171.61 us | 303.26 ns | 34.32 us | 115.21 us | 3 | 56 bytes | 19 bytes | 0 | 0 bytes | 0 bytes | 56 bytes | +-- | sql/pid | 3 | 220.55 us | 29.29 us | 73.52 us | 143.11 us | 0 | 0 bytes | 0 bytes | 1 | 5 bytes | 5 bytes | 5 bytes | +-- | sql/casetest | 1 | 121.19 us | 121.19 us | 121.19 us | 121.19 us | 0 | 0 bytes | 0 bytes | 0 | 0 bytes | 0 bytes | 0 bytes | +-- | sql/binlog_index | 5 | 593.47 us | 1.07 us | 118.69 us | 535.90 us | 0 | 0 bytes | 0 bytes | 0 | 0 bytes | 0 bytes | 0 bytes | +-- | sql/misc | 23 | 2.73 ms | 65.14 us | 118.50 us | 255.31 us | 0 | 0 bytes | 0 bytes | 0 | 0 bytes | 0 bytes | 0 bytes | +-- +--------------------+--------+---------------+-------------+-------------+-------------+------------+------------+-----------+-------------+---------------+-------------+-----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW io_global_by_wait_by_bytes ( + event_name, + total, + total_latency, + min_latency, + avg_latency, + max_latency, + count_read, + total_read, + avg_read, + count_write, + total_written, + avg_written, + total_requested +) AS +SELECT SUBSTRING_INDEX(event_name, '/', -2) event_name, + count_star AS total, + sys.format_time(sum_timer_wait) AS total_latency, + sys.format_time(min_timer_wait) AS min_latency, + sys.format_time(avg_timer_wait) AS avg_latency, + sys.format_time(max_timer_wait) AS max_latency, + count_read, + sys.format_bytes(sum_number_of_bytes_read) AS total_read, + sys.format_bytes(IFNULL(sum_number_of_bytes_read / NULLIF(count_read, 0), 0)) AS avg_read, + count_write, + sys.format_bytes(sum_number_of_bytes_write) AS total_written, + sys.format_bytes(IFNULL(sum_number_of_bytes_write / NULLIF(count_write, 0), 0)) AS avg_written, + sys.format_bytes(sum_number_of_bytes_write + sum_number_of_bytes_read) AS total_requested + FROM performance_schema.file_summary_by_event_name + WHERE event_name LIKE 'wait/io/file/%' + AND count_star > 0 + ORDER BY sum_number_of_bytes_write + sum_number_of_bytes_read DESC; diff --git a/scripts/sys_schema/views/p_s/io_global_by_wait_by_latency.sql b/scripts/sys_schema/views/p_s/io_global_by_wait_by_latency.sql new file mode 100644 index 00000000..5783e98c --- /dev/null +++ b/scripts/sys_schema/views/p_s/io_global_by_wait_by_latency.sql @@ -0,0 +1,81 @@ +-- 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: io_global_by_wait_by_latency +-- +-- Shows the top global IO consumers by latency. +-- +-- mysql> SELECT * FROM io_global_by_wait_by_latency; +-- +-------------------------+-------+---------------+-------------+-------------+--------------+---------------+--------------+------------+------------+-----------+-------------+---------------+-------------+ +-- | event_name | total | total_latency | avg_latency | max_latency | read_latency | write_latency | misc_latency | count_read | total_read | avg_read | count_write | total_written | avg_written | +-- +-------------------------+-------+---------------+-------------+-------------+--------------+---------------+--------------+------------+------------+-----------+-------------+---------------+-------------+ +-- | sql/file_parser | 5433 | 30.20 s | 5.56 ms | 203.65 ms | 22.08 ms | 24.89 ms | 30.16 s | 24 | 6.18 KiB | 264 bytes | 737 | 2.15 MiB | 2.99 KiB | +-- | innodb/innodb_data_file | 1344 | 1.52 s | 1.13 ms | 350.70 ms | 203.82 ms | 450.96 ms | 868.21 ms | 147 | 2.30 MiB | 16.00 KiB | 1001 | 53.61 MiB | 54.84 KiB | +-- | innodb/innodb_log_file | 828 | 893.48 ms | 1.08 ms | 30.11 ms | 16.32 ms | 705.89 ms | 171.27 ms | 6 | 68.00 KiB | 11.33 KiB | 413 | 2.19 MiB | 5.42 KiB | +-- | myisam/kfile | 7642 | 242.34 ms | 31.71 us | 19.27 ms | 73.60 ms | 23.48 ms | 145.26 ms | 758 | 135.63 KiB | 183 bytes | 4386 | 232.52 KiB | 54 bytes | +-- | myisam/dfile | 12540 | 223.47 ms | 17.82 us | 32.50 ms | 87.76 ms | 16.97 ms | 118.74 ms | 5390 | 4.49 MiB | 873 bytes | 1448 | 2.65 MiB | 1.88 KiB | +-- | csv/metadata | 8 | 28.98 ms | 3.62 ms | 20.15 ms | 399.27 us | 0 ps | 28.58 ms | 2 | 70 bytes | 35 bytes | 0 | 0 bytes | 0 bytes | +-- | mysys/charset | 3 | 24.24 ms | 8.08 ms | 24.15 ms | 24.15 ms | 0 ps | 93.18 us | 1 | 17.31 KiB | 17.31 KiB | 0 | 0 bytes | 0 bytes | +-- | sql/ERRMSG | 5 | 20.43 ms | 4.09 ms | 19.31 ms | 20.32 ms | 0 ps | 103.20 us | 3 | 58.97 KiB | 19.66 KiB | 0 | 0 bytes | 0 bytes | +-- | mysys/cnf | 5 | 11.37 ms | 2.27 ms | 11.28 ms | 11.29 ms | 0 ps | 78.22 us | 3 | 56 bytes | 19 bytes | 0 | 0 bytes | 0 bytes | +-- | sql/dbopt | 57 | 4.04 ms | 70.92 us | 843.70 us | 0 ps | 186.43 us | 3.86 ms | 0 | 0 bytes | 0 bytes | 7 | 431 bytes | 62 bytes | +-- | csv/data | 4 | 411.55 us | 102.89 us | 234.89 us | 0 ps | 0 ps | 411.55 us | 0 | 0 bytes | 0 bytes | 0 | 0 bytes | 0 bytes | +-- | sql/misc | 22 | 340.38 us | 15.47 us | 33.77 us | 0 ps | 0 ps | 340.38 us | 0 | 0 bytes | 0 bytes | 0 | 0 bytes | 0 bytes | +-- | archive/data | 39 | 277.86 us | 7.12 us | 16.18 us | 0 ps | 0 ps | 277.86 us | 0 | 0 bytes | 0 bytes | 0 | 0 bytes | 0 bytes | +-- | sql/pid | 3 | 218.03 us | 72.68 us | 154.84 us | 0 ps | 21.64 us | 196.39 us | 0 | 0 bytes | 0 bytes | 1 | 6 bytes | 6 bytes | +-- | sql/casetest | 5 | 197.15 us | 39.43 us | 126.31 us | 0 ps | 0 ps | 197.15 us | 0 | 0 bytes | 0 bytes | 0 | 0 bytes | 0 bytes | +-- | sql/global_ddl_log | 2 | 14.60 us | 7.30 us | 12.12 us | 0 ps | 0 ps | 14.60 us | 0 | 0 bytes | 0 bytes | 0 | 0 bytes | 0 bytes | +-- +-------------------------+-------+---------------+-------------+-------------+--------------+---------------+--------------+------------+------------+-----------+-------------+---------------+-------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW io_global_by_wait_by_latency ( + event_name, + total, + total_latency, + avg_latency, + max_latency, + read_latency, + write_latency, + misc_latency, + count_read, + total_read, + avg_read, + count_write, + total_written, + avg_written +) AS +SELECT SUBSTRING_INDEX(event_name, '/', -2) AS event_name, + count_star AS total, + sys.format_time(sum_timer_wait) AS total_latency, + sys.format_time(avg_timer_wait) AS avg_latency, + sys.format_time(max_timer_wait) AS max_latency, + sys.format_time(sum_timer_read) AS read_latency, + sys.format_time(sum_timer_write) AS write_latency, + sys.format_time(sum_timer_misc) AS misc_latency, + count_read, + sys.format_bytes(sum_number_of_bytes_read) AS total_read, + sys.format_bytes(IFNULL(sum_number_of_bytes_read / NULLIF(count_read, 0), 0)) AS avg_read, + count_write, + sys.format_bytes(sum_number_of_bytes_write) AS total_written, + sys.format_bytes(IFNULL(sum_number_of_bytes_write / NULLIF(count_write, 0), 0)) AS avg_written + FROM performance_schema.file_summary_by_event_name + WHERE event_name LIKE 'wait/io/file/%' + AND count_star > 0 + ORDER BY sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/latest_file_io.sql b/scripts/sys_schema/views/p_s/latest_file_io.sql new file mode 100644 index 00000000..9803cc6c --- /dev/null +++ b/scripts/sys_schema/views/p_s/latest_file_io.sql @@ -0,0 +1,57 @@ +-- 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: latest_file_io +-- +-- Shows the latest file IO, by file / thread. +-- +-- mysql> select * from latest_file_io limit 5; +-- +----------------------+----------------------------------------+------------+-----------+-----------+ +-- | thread | file | latency | operation | requested | +-- +----------------------+----------------------------------------+------------+-----------+-----------+ +-- | msandbox@localhost:1 | @@tmpdir/#sqlcf28_1_4e.MYI | 9.26 us | write | 124 bytes | +-- | msandbox@localhost:1 | @@tmpdir/#sqlcf28_1_4e.MYI | 4.00 us | write | 2 bytes | +-- | msandbox@localhost:1 | @@tmpdir/#sqlcf28_1_4e.MYI | 56.34 us | close | NULL | +-- | msandbox@localhost:1 | @@tmpdir/#sqlcf28_1_4e.MYD | 53.93 us | close | NULL | +-- | msandbox@localhost:1 | @@tmpdir/#sqlcf28_1_4e.MYI | 104.05 ms | delete | NULL | +-- +----------------------+----------------------------------------+------------+-----------+-----------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW latest_file_io ( + thread, + file, + latency, + operation, + requested +) AS +SELECT IF(id IS NULL, + CONCAT(SUBSTRING_INDEX(name, '/', -1), ':', thread_id), + CONCAT(user, '@', host, ':', id) + ) thread, + sys.format_path(object_name) file, + sys.format_time(timer_wait) AS latency, + operation, + sys.format_bytes(number_of_bytes) AS requested + FROM performance_schema.events_waits_history_long + JOIN performance_schema.threads USING (thread_id) + LEFT JOIN information_schema.processlist ON processlist_id = id + WHERE object_name IS NOT NULL + AND event_name LIKE 'wait/io/file/%' + ORDER BY timer_start; diff --git a/scripts/sys_schema/views/p_s/memory_by_host_by_current_bytes.sql b/scripts/sys_schema/views/p_s/memory_by_host_by_current_bytes.sql new file mode 100644 index 00000000..ca6ce2da --- /dev/null +++ b/scripts/sys_schema/views/p_s/memory_by_host_by_current_bytes.sql @@ -0,0 +1,52 @@ +-- 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: memory_by_host_by_current_bytes +-- +-- Summarizes memory use by host using the 5.7 Performance Schema instrumentation. +-- +-- When the host found is NULL, it is assumed to be a local "background" thread. +-- +-- mysql> select * from memory_by_host_by_current_bytes; +-- +------------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- | host | current_count_used | current_allocated | current_avg_alloc | current_max_alloc | total_allocated | +-- +------------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- | background | 2773 | 10.84 MiB | 4.00 KiB | 8.00 MiB | 30.69 MiB | +-- | localhost | 1509 | 809.30 KiB | 549 bytes | 176.38 KiB | 83.59 MiB | +-- +------------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW memory_by_host_by_current_bytes ( + host, + current_count_used, + current_allocated, + current_avg_alloc, + current_max_alloc, + total_allocated +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + SUM(current_count_used) AS current_count_used, + sys.format_bytes(SUM(current_number_of_bytes_used)) AS current_allocated, + sys.format_bytes(IFNULL(SUM(current_number_of_bytes_used) / NULLIF(SUM(current_count_used), 0), 0)) AS current_avg_alloc, + sys.format_bytes(MAX(current_number_of_bytes_used)) AS current_max_alloc, + sys.format_bytes(SUM(sum_number_of_bytes_alloc)) AS total_allocated + FROM performance_schema.memory_summary_by_host_by_event_name + GROUP BY IF(host IS NULL, 'background', host) + ORDER BY SUM(current_number_of_bytes_used) DESC; diff --git a/scripts/sys_schema/views/p_s/memory_by_thread_by_current_bytes.sql b/scripts/sys_schema/views/p_s/memory_by_thread_by_current_bytes.sql new file mode 100644 index 00000000..6db9d79c --- /dev/null +++ b/scripts/sys_schema/views/p_s/memory_by_thread_by_current_bytes.sql @@ -0,0 +1,62 @@ +-- 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: memory_by_thread_by_current_bytes +-- +-- Summarizes memory use by user using the 5.7 Performance Schema instrumentation. +-- +-- User shows either the background or foreground user name appropriately. +-- +-- mysql> select * from sys.memory_by_thread_by_current_bytes limit 5; +-- +-----------+----------------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- | thread_id | user | current_count_used | current_allocated | current_avg_alloc | current_max_alloc | total_allocated | +-- +-----------+----------------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- | 1 | sql/main | 29333 | 166.02 MiB | 5.80 KiB | 131.13 MiB | 196.00 MiB | +-- | 55 | root@localhost | 175 | 1.04 MiB | 6.09 KiB | 350.86 KiB | 67.37 MiB | +-- | 58 | root@localhost | 236 | 368.13 KiB | 1.56 KiB | 312.05 KiB | 130.34 MiB | +-- | 904 | root@localhost | 32 | 18.00 KiB | 576 bytes | 16.00 KiB | 6.68 MiB | +-- | 970 | root@localhost | 12 | 16.80 KiB | 1.40 KiB | 16.00 KiB | 1.20 MiB | +-- +-----------+----------------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW memory_by_thread_by_current_bytes ( + thread_id, + user, + current_count_used, + current_allocated, + current_avg_alloc, + current_max_alloc, + total_allocated +) AS +SELECT thread_id, + IF(t.name = 'thread/sql/one_connection', + CONCAT(t.processlist_user, '@', t.processlist_host), + REPLACE(t.name, 'thread/', '')) user, + SUM(mt.current_count_used) AS current_count_used, + sys.format_bytes(SUM(mt.current_number_of_bytes_used)) AS current_allocated, + sys.format_bytes(IFNULL(SUM(mt.current_number_of_bytes_used) / NULLIF(SUM(current_count_used), 0), 0)) AS current_avg_alloc, + sys.format_bytes(MAX(mt.current_number_of_bytes_used)) AS current_max_alloc, + sys.format_bytes(SUM(mt.sum_number_of_bytes_alloc)) AS total_allocated + FROM performance_schema.memory_summary_by_thread_by_event_name AS mt + JOIN performance_schema.threads AS t USING (thread_id) + GROUP BY thread_id, IF(t.name = 'thread/sql/one_connection', + CONCAT(t.processlist_user, '@', t.processlist_host), + REPLACE(t.name, 'thread/', '')) + ORDER BY SUM(current_number_of_bytes_used) DESC; diff --git a/scripts/sys_schema/views/p_s/memory_by_user_by_current_bytes.sql b/scripts/sys_schema/views/p_s/memory_by_user_by_current_bytes.sql new file mode 100644 index 00000000..efb5267e --- /dev/null +++ b/scripts/sys_schema/views/p_s/memory_by_user_by_current_bytes.sql @@ -0,0 +1,52 @@ +-- 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: memory_by_user_by_current_bytes +-- +-- Summarizes memory use by user using the 5.7 Performance Schema instrumentation. +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from memory_by_user_by_current_bytes; +-- +------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- | user | current_count_used | current_allocated | current_avg_alloc | current_max_alloc | total_allocated | +-- +------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- | root | 1401 | 1.09 MiB | 815 bytes | 334.97 KiB | 42.73 MiB | +-- | mark | 201 | 496.08 KiB | 2.47 KiB | 334.97 KiB | 5.50 MiB | +-- +------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW memory_by_user_by_current_bytes ( + user, + current_count_used, + current_allocated, + current_avg_alloc, + current_max_alloc, + total_allocated +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + SUM(current_count_used) AS current_count_used, + sys.format_bytes(SUM(current_number_of_bytes_used)) AS current_allocated, + sys.format_bytes(IFNULL(SUM(current_number_of_bytes_used) / NULLIF(SUM(current_count_used), 0), 0)) AS current_avg_alloc, + sys.format_bytes(MAX(current_number_of_bytes_used)) AS current_max_alloc, + sys.format_bytes(SUM(sum_number_of_bytes_alloc)) AS total_allocated + FROM performance_schema.memory_summary_by_user_by_event_name + GROUP BY IF(user IS NULL, 'background', user) + ORDER BY SUM(current_number_of_bytes_used) DESC; diff --git a/scripts/sys_schema/views/p_s/memory_global_by_current_bytes.sql b/scripts/sys_schema/views/p_s/memory_global_by_current_bytes.sql new file mode 100644 index 00000000..c1e9f27e --- /dev/null +++ b/scripts/sys_schema/views/p_s/memory_global_by_current_bytes.sql @@ -0,0 +1,56 @@ +-- 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: memory_global_by_current_bytes +-- +-- Shows the current memory usage within the server globally broken down by allocation type. +-- +-- mysql> select * from memory_global_by_current_bytes; +-- +-------------------------------------------------+---------------+---------------+-------------------+------------+-------------+----------------+ +-- | event_name | current_count | current_alloc | current_avg_alloc | high_count | high_alloc | high_avg_alloc | +-- +-------------------------------------------------+---------------+---------------+-------------------+------------+-------------+----------------+ +-- | memory/performance_schema/internal_buffers | 62 | 293.80 MiB | 4.74 MiB | 62 | 293.80 MiB | 4.74 MiB | +-- | memory/innodb/buf_buf_pool | 1 | 131.06 MiB | 131.06 MiB | 1 | 131.06 MiB | 131.06 MiB | +-- | memory/innodb/log0log | 9 | 8.01 MiB | 911.15 KiB | 9 | 8.01 MiB | 911.15 KiB | +-- | memory/mysys/KEY_CACHE | 3 | 8.00 MiB | 2.67 MiB | 3 | 8.00 MiB | 2.67 MiB | +-- | memory/innodb/hash0hash | 27 | 4.73 MiB | 179.51 KiB | 27 | 6.84 MiB | 259.47 KiB | +-- | memory/innodb/os0event | 24998 | 4.01 MiB | 168 bytes | 24998 | 4.01 MiB | 168 bytes | +-- ... +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW memory_global_by_current_bytes ( + event_name, + current_count, + current_alloc, + current_avg_alloc, + high_count, + high_alloc, + high_avg_alloc +) AS +SELECT event_name, + current_count_used AS current_count, + sys.format_bytes(current_number_of_bytes_used) AS current_alloc, + sys.format_bytes(IFNULL(current_number_of_bytes_used / NULLIF(current_count_used, 0), 0)) AS current_avg_alloc, + high_count_used AS high_count, + sys.format_bytes(high_number_of_bytes_used) AS high_alloc, + sys.format_bytes(IFNULL(high_number_of_bytes_used / NULLIF(high_count_used, 0), 0)) AS high_avg_alloc + FROM performance_schema.memory_summary_global_by_event_name + WHERE current_number_of_bytes_used > 0 + ORDER BY current_number_of_bytes_used DESC; diff --git a/scripts/sys_schema/views/p_s/memory_global_total.sql b/scripts/sys_schema/views/p_s/memory_global_total.sql new file mode 100644 index 00000000..8d014e9d --- /dev/null +++ b/scripts/sys_schema/views/p_s/memory_global_total.sql @@ -0,0 +1,37 @@ +-- 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: memory_global_total +-- +-- Shows the total memory usage within the server globally. +-- +-- mysql> select * from memory_global_total; +-- +-----------------+ +-- | total_allocated | +-- +-----------------+ +-- | 123.35 MiB | +-- +-----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW memory_global_total ( + total_allocated +) AS +SELECT sys.format_bytes(SUM(CURRENT_NUMBER_OF_BYTES_USED)) total_allocated + FROM performance_schema.memory_summary_global_by_event_name; diff --git a/scripts/sys_schema/views/p_s/metrics.sql b/scripts/sys_schema/views/p_s/metrics.sql new file mode 100644 index 00000000..0fcc5c5e --- /dev/null +++ b/scripts/sys_schema/views/p_s/metrics.sql @@ -0,0 +1,126 @@ +-- Copyright (c) 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 + +-- IMPORTANT +-- If you update this view, also update the "5.7+ and the Performance Schema disabled" +-- query in procedures/diagnostics.sql + +-- View: metrics +-- +-- Creates a union of the following information: +-- +-- * performance_schema.global_status +-- * information_schema.INNODB_METRICS +-- * Performance Schema global memory usage information +-- * Current time +-- +-- This is the same as the metrics_56 view with the exception that the global status is taken from performance_schema.global_status instead of +-- from the Information Schema. Use this view if the MySQL version is 5.7.6 or later and show_compatibility_56 = OFF. +-- See also https://dev.mysql.com/doc/refman/5.7/en/server-system-variables.html#sysvar_show_compatibility_56 +-- +-- For view has the following columns: +-- +-- * Variable_name: The name of the variable +-- * Variable_value: The value of the variable +-- * Type: The type of the variable. This will depend on the source, e.g. Global Status, InnoDB Metrics - ..., etc. +-- * Enabled: Whether the variable is enabled or not. Possible values are 'YES', 'NO', 'PARTIAL'. +-- PARTIAL is currently only supported for the memory usage variables and means some but not all of the memory/% instruments +-- are enabled. +-- +-- mysql> SELECT * FROM metrics; +-- +-----------------------------------------------+-------------------------...+--------------------------------------+---------+ +-- | Variable_name | Variable_value ...| Type | Enabled | +-- +-----------------------------------------------+-------------------------...+--------------------------------------+---------+ +-- | aborted_clients | 0 ...| Global Status | YES | +-- | aborted_connects | 0 ...| Global Status | YES | +-- | binlog_cache_disk_use | 0 ...| Global Status | YES | +-- | binlog_cache_use | 0 ...| Global Status | YES | +-- | binlog_stmt_cache_disk_use | 0 ...| Global Status | YES | +-- | binlog_stmt_cache_use | 0 ...| Global Status | YES | +-- | bytes_received | 217081 ...| Global Status | YES | +-- | bytes_sent | 27257 ...| Global Status | YES | +-- ... +-- | innodb_rwlock_x_os_waits | 0 ...| InnoDB Metrics - server | YES | +-- | innodb_rwlock_x_spin_rounds | 2723 ...| InnoDB Metrics - server | YES | +-- | innodb_rwlock_x_spin_waits | 1 ...| InnoDB Metrics - server | YES | +-- | trx_active_transactions | 0 ...| InnoDB Metrics - transaction | NO | +-- ... +-- | trx_rseg_current_size | 0 ...| InnoDB Metrics - transaction | NO | +-- | trx_rseg_history_len | 4 ...| InnoDB Metrics - transaction | YES | +-- | trx_rw_commits | 0 ...| InnoDB Metrics - transaction | NO | +-- | trx_undo_slots_cached | 0 ...| InnoDB Metrics - transaction | NO | +-- | trx_undo_slots_used | 0 ...| InnoDB Metrics - transaction | NO | +-- | memory_current_allocated | 138244216 ...| Performance Schema | PARTIAL | +-- | memory_total_allocated | 138244216 ...| Performance Schema | PARTIAL | +-- | NOW() | 2015-05-31 13:27:50.382 ...| System Time | YES | +-- | UNIX_TIMESTAMP() | 1433042870.382 ...| System Time | YES | +-- +-----------------------------------------------+-------------------------...+--------------------------------------+---------+ +-- 412 rows in set (0.02 sec) +DELIMITER $$ +BEGIN NOT ATOMIC +DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN END; + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW metrics ( + Variable_name, + Variable_value, + Type, + Enabled +) AS +( +SELECT LOWER(VARIABLE_NAME) AS Variable_name, VARIABLE_VALUE AS Variable_value, 'Global Status' AS Type, 'YES' AS Enabled + FROM performance_schema.global_status +) UNION ALL ( +SELECT NAME AS Variable_name, COUNT AS Variable_value, + CONCAT('InnoDB Metrics - ', SUBSYSTEM) AS Type, + 'YES' AS Enabled + FROM information_schema.INNODB_METRICS + -- Deduplication - some variables exists both in GLOBAL_STATUS and INNODB_METRICS + -- Keep the one from GLOBAL_STATUS as it is always enabled and it's more likely to be used for existing tools. + WHERE NAME NOT IN ( + 'lock_row_lock_time', 'lock_row_lock_time_avg', 'lock_row_lock_time_max', 'lock_row_lock_waits', + 'buffer_pool_reads', 'buffer_pool_read_requests', 'buffer_pool_write_requests', 'buffer_pool_wait_free', + 'buffer_pool_read_ahead', 'buffer_pool_read_ahead_evicted', 'buffer_pool_pages_total', 'buffer_pool_pages_misc', + 'buffer_pool_pages_data', 'buffer_pool_bytes_data', 'buffer_pool_pages_dirty', 'buffer_pool_bytes_dirty', + 'buffer_pool_pages_free', 'buffer_pages_created', 'buffer_pages_written', 'buffer_pages_read', + 'buffer_data_reads', 'buffer_data_written', 'file_num_open_files', + 'os_log_bytes_written', 'os_log_fsyncs', 'os_log_pending_fsyncs', 'os_log_pending_writes', + 'log_waits', 'log_write_requests', 'log_writes', 'innodb_dblwr_writes', 'innodb_dblwr_pages_written', 'innodb_page_size') +) /*!50702 + -- memory instrumentation available in 5.7.2 and later + UNION ALL ( +SELECT 'memory_current_allocated' AS Variable_name, SUM(CURRENT_NUMBER_OF_BYTES_USED) AS Variable_value, 'Performance Schema' AS Type, + IF((SELECT COUNT(*) FROM performance_schema.setup_instruments WHERE NAME LIKE 'memory/%' AND ENABLED = 'YES') = 0, 'NO', + IF((SELECT COUNT(*) FROM performance_schema.setup_instruments WHERE NAME LIKE 'memory/%' AND ENABLED = 'YES') = (SELECT COUNT(*) FROM performance_schema.setup_instruments WHERE NAME LIKE 'memory/%'), 'YES', + 'PARTIAL')) AS Enabled + FROM performance_schema.memory_summary_global_by_event_name +) UNION ALL ( +SELECT 'memory_total_allocated' AS Variable_name, SUM(SUM_NUMBER_OF_BYTES_ALLOC) AS Variable_value, 'Performance Schema' AS Type, + IF((SELECT COUNT(*) FROM performance_schema.setup_instruments WHERE NAME LIKE 'memory/%' AND ENABLED = 'YES') = 0, 'NO', + IF((SELECT COUNT(*) FROM performance_schema.setup_instruments WHERE NAME LIKE 'memory/%' AND ENABLED = 'YES') = (SELECT COUNT(*) FROM performance_schema.setup_instruments WHERE NAME LIKE 'memory/%'), 'YES', + 'PARTIAL')) AS Enabled + FROM performance_schema.memory_summary_global_by_event_name +) */ + UNION ALL ( +SELECT 'NOW()' AS Variable_name, NOW(3) AS Variable_value, 'System Time' AS Type, 'YES' AS Enabled +) UNION ALL ( +SELECT 'UNIX_TIMESTAMP()' AS Variable_name, ROUND(UNIX_TIMESTAMP(NOW(3)), 3) AS Variable_value, 'System Time' AS Type, 'YES' AS Enabled +) + ORDER BY Type, Variable_name; +END$$ +DELIMITER ;
\ No newline at end of file diff --git a/scripts/sys_schema/views/p_s/metrics_56.sql b/scripts/sys_schema/views/p_s/metrics_56.sql new file mode 100644 index 00000000..79447ae7 --- /dev/null +++ b/scripts/sys_schema/views/p_s/metrics_56.sql @@ -0,0 +1,112 @@ +-- Copyright (c) 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: metrics +-- +-- Creates a union of the following information: +-- +-- * information_schema.GLOBAL_STATUS +-- * information_schema.INNODB_METRICS +-- * Performance Schema global memory usage information +-- * Current time +-- +-- This is the same as the metrics view with the exception that the global status is taken from information_schema.GLOBAL_STATUS instead of +-- from the Peformance Schema. Use this view if one of the following conditions are fulfilled: +-- +-- * The MySQL version is 5.6 or 5.7.0-5.7.5 +-- * In 5.7.6 and later if show_compatibility_56 is ON. See also https://dev.mysql.com/doc/refman/5.7/en/server-system-variables.html#sysvar_show_compatibility_56 +-- +-- In MySQL 5.7.6 and later the view will generate one warning: +-- mysql> SHOW WARNINGS; +-- +---------+------+-----------------------------------------------------------------------------------------------------------------------------------------------+ +-- | Level | Code | Message | +-- +---------+------+-----------------------------------------------------------------------------------------------------------------------------------------------+ +-- | Warning | 1287 | 'INFORMATION_SCHEMA.GLOBAL_STATUS' is deprecated and will be removed in a future release. Please use performance_schema.global_status instead | +-- +---------+------+-----------------------------------------------------------------------------------------------------------------------------------------------+ +-- 1 row in set (0.00 sec) +-- +-- For view has the following columns: +-- +-- * Variable_name: The name of the variable +-- * Variable_value: The value of the variable +-- * Type: The type of the variable. This will depend on the source, e.g. Global Status, InnoDB Metrics - ..., etc. +-- * Enabled: Whether the variable is enabled or not. Possible values are 'YES', 'NO', 'PARTIAL'. +-- PARTIAL is currently only supported for the memory usage variables and means some but not all of the memory/% instruments +-- are enabled. +-- +-- mysql> SELECT * FROM metrics; +-- +-----------------------------------------------+-------------------------...+--------------------------------------+---------+ +-- | Variable_name | Variable_value ...| Type | Enabled | +-- +-----------------------------------------------+-------------------------...+--------------------------------------+---------+ +-- | aborted_clients | 0 ...| Global Status | YES | +-- | aborted_connects | 0 ...| Global Status | YES | +-- | binlog_cache_disk_use | 0 ...| Global Status | YES | +-- | binlog_cache_use | 0 ...| Global Status | YES | +-- | binlog_stmt_cache_disk_use | 0 ...| Global Status | YES | +-- | binlog_stmt_cache_use | 0 ...| Global Status | YES | +-- | bytes_received | 217081 ...| Global Status | YES | +-- | bytes_sent | 27257 ...| Global Status | YES | +-- ... +-- | innodb_rwlock_x_os_waits | 0 ...| InnoDB Metrics - server | YES | +-- | innodb_rwlock_x_spin_rounds | 2723 ...| InnoDB Metrics - server | YES | +-- | innodb_rwlock_x_spin_waits | 1 ...| InnoDB Metrics - server | YES | +-- | trx_active_transactions | 0 ...| InnoDB Metrics - transaction | NO | +-- ... +-- | trx_rseg_current_size | 0 ...| InnoDB Metrics - transaction | NO | +-- | trx_rseg_history_len | 4 ...| InnoDB Metrics - transaction | YES | +-- | trx_rw_commits | 0 ...| InnoDB Metrics - transaction | NO | +-- | trx_undo_slots_cached | 0 ...| InnoDB Metrics - transaction | NO | +-- | trx_undo_slots_used | 0 ...| InnoDB Metrics - transaction | NO | +-- | NOW() | 2015-05-31 13:27:50.382 ...| System Time | YES | +-- | UNIX_TIMESTAMP() | 1433042870.382 ...| System Time | YES | +-- +-----------------------------------------------+-------------------------...+--------------------------------------+---------+ +-- 565 rows in set, 1 warning (0.02 sec) + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW metrics ( + Variable_name, + Variable_value, + Type, + Enabled +) AS +( +SELECT LOWER(VARIABLE_NAME) AS Variable_name, VARIABLE_VALUE AS Variable_value, 'Global Status' AS Type, 'YES' AS Enabled + FROM information_schema.GLOBAL_STATUS +) UNION ALL ( +SELECT NAME AS Variable_name, COUNT AS Variable_value, + CONCAT('InnoDB Metrics - ', SUBSYSTEM) AS Type, + IF(STATUS = 'enabled', 'YES', 'NO') AS Enabled + FROM information_schema.INNODB_METRICS + -- Deduplication - some variables exists both in GLOBAL_STATUS and INNODB_METRICS + -- Keep the one from GLOBAL_STATUS as it is always enabled and it's more likely to be used for existing tools. + WHERE NAME NOT IN ( + 'lock_row_lock_time', 'lock_row_lock_time_avg', 'lock_row_lock_time_max', 'lock_row_lock_waits', + 'buffer_pool_reads', 'buffer_pool_read_requests', 'buffer_pool_write_requests', 'buffer_pool_wait_free', + 'buffer_pool_read_ahead', 'buffer_pool_read_ahead_evicted', 'buffer_pool_pages_total', 'buffer_pool_pages_misc', + 'buffer_pool_pages_data', 'buffer_pool_bytes_data', 'buffer_pool_pages_dirty', 'buffer_pool_bytes_dirty', + 'buffer_pool_pages_free', 'buffer_pages_created', 'buffer_pages_written', 'buffer_pages_read', + 'buffer_data_reads', 'buffer_data_written', 'file_num_open_files', + 'os_log_bytes_written', 'os_log_fsyncs', 'os_log_pending_fsyncs', 'os_log_pending_writes', + 'log_waits', 'log_write_requests', 'log_writes', 'innodb_dblwr_writes', 'innodb_dblwr_pages_written', 'innodb_page_size') +) UNION ALL ( +SELECT 'NOW()' AS Variable_name, NOW(3) AS Variable_value, 'System Time' AS Type, 'YES' AS Enabled +) UNION ALL ( +SELECT 'UNIX_TIMESTAMP()' AS Variable_name, ROUND(UNIX_TIMESTAMP(NOW(3)), 3) AS Variable_value, 'System Time' AS Type, 'YES' AS Enabled +) + ORDER BY Type, Variable_name; diff --git a/scripts/sys_schema/views/p_s/processlist.sql b/scripts/sys_schema/views/p_s/processlist.sql new file mode 100644 index 00000000..33e8969f --- /dev/null +++ b/scripts/sys_schema/views/p_s/processlist.sql @@ -0,0 +1,108 @@ +-- 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: processlist +-- +-- A detailed non-blocking processlist view to replace +-- [INFORMATION_SCHEMA. | SHOW FULL] PROCESSLIST +-- +-- mysql> select * from processlist where conn_id is not null\G +-- *************************** 1. row *************************** +-- thd_id: 23 +-- conn_id: 4 +-- user: msandbox@localhost +-- db: test +-- command: Query +-- state: Sending data +-- time: 4 +-- current_statement: select count(*) from t1 +-- statement_latency: 4.56 s +-- lock_latency: 108.00 us +-- rows_examined: 0 +-- rows_sent: 0 +-- rows_affected: 0 +-- tmp_tables: 0 +-- tmp_disk_tables: 0 +-- full_scan: YES +-- last_statement: NULL +-- last_statement_latency: NULL +-- last_wait: wait/io/table/sql/handler +-- last_wait_latency: Still Waiting +-- source: handler.cc:2688 +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW processlist ( + thd_id, + conn_id, + user, + db, + command, + state, + time, + current_statement, + statement_latency, + lock_latency, + rows_examined, + rows_sent, + rows_affected, + tmp_tables, + tmp_disk_tables, + full_scan, + last_statement, + last_statement_latency, + last_wait, + last_wait_latency, + source +) 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, + sys.format_statement(pps.processlist_info) AS current_statement, + IF(esc.end_event_id IS NULL, + sys.format_time(esc.timer_wait), + NULL) AS statement_latency, + sys.format_time(esc.lock_time) AS lock_latency, + esc.rows_examined AS rows_examined, + esc.rows_sent AS rows_sent, + esc.rows_affected AS 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, + IF(esc.end_event_id IS NOT NULL, + sys.format_statement(esc.sql_text), + NULL) AS last_statement, + IF(esc.end_event_id IS NOT NULL, + sys.format_time(esc.timer_wait), + NULL) AS last_statement_latency, + ewc.event_name AS last_wait, + IF(ewc.end_event_id IS NULL AND ewc.event_name IS NOT NULL, + 'Still Waiting', + sys.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; diff --git a/scripts/sys_schema/views/p_s/processlist_57.sql b/scripts/sys_schema/views/p_s/processlist_57.sql new file mode 100644 index 00000000..4e4f21ea --- /dev/null +++ b/scripts/sys_schema/views/p_s/processlist_57.sql @@ -0,0 +1,140 @@ +-- 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: processlist +-- +-- A detailed non-blocking processlist view to replace +-- [INFORMATION_SCHEMA. | SHOW FULL] PROCESSLIST +-- +-- Performs less locking than the legacy sources, whilst giving extra information. +-- +-- mysql> select * from sys.processlist where conn_id is not null and command != 'daemon' and conn_id != connection_id()\G +-- *************************** 1. row *************************** +-- thd_id: 44524 +-- conn_id: 44502 +-- user: msandbox@localhost +-- db: test +-- command: Query +-- state: alter table (flush) +-- time: 18 +-- current_statement: alter table t1 add column g int +-- statement_latency: 18.45 s +-- progress: 98.84 +-- lock_latency: 265.43 ms +-- rows_examined: 0 +-- rows_sent: 0 +-- rows_affected: 0 +-- tmp_tables: 0 +-- tmp_disk_tables: 0 +-- full_scan: NO +-- last_statement: NULL +-- last_statement_latency: NULL +-- current_memory: 664.06 KiB +-- last_wait: wait/io/file/innodb/innodb_data_file +-- last_wait_latency: 1.07 us +-- source: fil0fil.cc:5146 +-- trx_latency: NULL +-- trx_state: NULL +-- trx_autocommit: NULL +-- pid: 4212 +-- program_name: mysql +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW processlist ( + thd_id, + conn_id, + user, + db, + command, + state, + time, + current_statement, + statement_latency, + progress, + lock_latency, + rows_examined, + rows_sent, + rows_affected, + tmp_tables, + tmp_disk_tables, + full_scan, + last_statement, + last_statement_latency, + current_memory, + last_wait, + last_wait_latency, + source, + trx_latency, + trx_state, + trx_autocommit, + pid, + program_name +) 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, + sys.format_statement(pps.processlist_info) AS current_statement, + IF(esc.end_event_id IS NULL, + sys.format_time(esc.timer_wait), + NULL) AS statement_latency, + IF(esc.end_event_id IS NULL, + ROUND(100 * (estc.work_completed / estc.work_estimated), 2), + NULL) AS progress, + sys.format_time(esc.lock_time) AS lock_latency, + esc.rows_examined AS rows_examined, + esc.rows_sent AS rows_sent, + esc.rows_affected AS 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, + IF(esc.end_event_id IS NOT NULL, + sys.format_statement(esc.sql_text), + NULL) AS last_statement, + IF(esc.end_event_id IS NOT NULL, + sys.format_time(esc.timer_wait), + NULL) AS last_statement_latency, + sys.format_bytes(mem.current_allocated) AS current_memory, + ewc.event_name AS last_wait, + IF(ewc.end_event_id IS NULL AND ewc.event_name IS NOT NULL, + 'Still Waiting', + sys.format_time(ewc.timer_wait)) last_wait_latency, + ewc.source, + sys.format_time(etc.timer_wait) AS trx_latency, + etc.state AS trx_state, + etc.autocommit AS trx_autocommit, + conattr_pid.attr_value as pid, + conattr_progname.attr_value as program_name + FROM performance_schema.threads AS pps + LEFT JOIN performance_schema.events_waits_current AS ewc USING (thread_id) + LEFT JOIN performance_schema.events_stages_current AS estc USING (thread_id) + LEFT JOIN performance_schema.events_statements_current AS esc USING (thread_id) + LEFT JOIN performance_schema.events_transactions_current AS etc USING (thread_id) + LEFT JOIN sys.x$memory_by_thread_by_current_bytes AS mem USING (thread_id) + LEFT JOIN performance_schema.session_connect_attrs AS conattr_pid + ON conattr_pid.processlist_id=pps.processlist_id and conattr_pid.attr_name='_pid' + LEFT JOIN performance_schema.session_connect_attrs AS conattr_progname + ON conattr_progname.processlist_id=pps.processlist_id and conattr_progname.attr_name='program_name' + ORDER BY pps.processlist_time DESC, last_wait_latency DESC; diff --git a/scripts/sys_schema/views/p_s/ps_check_lost_instrumentation.sql b/scripts/sys_schema/views/p_s/ps_check_lost_instrumentation.sql new file mode 100644 index 00000000..21d8ecb6 --- /dev/null +++ b/scripts/sys_schema/views/p_s/ps_check_lost_instrumentation.sql @@ -0,0 +1,43 @@ +-- 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: ps_check_lost_instrumentation +-- +-- Used to check whether Performance Schema is not able to monitor +-- all runtime data - only returns variables that have lost instruments +-- +-- mysql> select * from ps_check_lost_instrumentation; +-- +----------------------------------------+----------------+ +-- | variable_name | variable_value | +-- +----------------------------------------+----------------+ +-- | Performance_schema_file_handles_lost | 101223 | +-- | Performance_schema_file_instances_lost | 1231 | +-- +----------------------------------------+----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW ps_check_lost_instrumentation ( + variable_name, + variable_value +) +AS +SELECT variable_name, variable_value + FROM information_schema.global_status + WHERE variable_name LIKE 'perf%lost' + AND variable_value > 0; diff --git a/scripts/sys_schema/views/p_s/ps_check_lost_instrumentation_57.sql b/scripts/sys_schema/views/p_s/ps_check_lost_instrumentation_57.sql new file mode 100644 index 00000000..25cc829b --- /dev/null +++ b/scripts/sys_schema/views/p_s/ps_check_lost_instrumentation_57.sql @@ -0,0 +1,43 @@ +-- 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: ps_check_lost_instrumentation +-- +-- Used to check whether Performance Schema is not able to monitor +-- all runtime data - only returns variables that have lost instruments +-- +-- mysql> select * from ps_check_lost_instrumentation; +-- +----------------------------------------+----------------+ +-- | variable_name | variable_value | +-- +----------------------------------------+----------------+ +-- | Performance_schema_file_handles_lost | 101223 | +-- | Performance_schema_file_instances_lost | 1231 | +-- +----------------------------------------+----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW ps_check_lost_instrumentation ( + variable_name, + variable_value +) +AS +SELECT variable_name, variable_value + FROM performance_schema.global_status + WHERE variable_name LIKE 'perf%lost' + AND variable_value > 0; diff --git a/scripts/sys_schema/views/p_s/schema_index_statistics.sql b/scripts/sys_schema/views/p_s/schema_index_statistics.sql new file mode 100644 index 00000000..84ce7ead --- /dev/null +++ b/scripts/sys_schema/views/p_s/schema_index_statistics.sql @@ -0,0 +1,65 @@ +-- 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: schema_index_statistics +-- +-- Statistics around indexes. +-- +-- Ordered by the total wait time descending - top indexes are most contended. +-- +-- mysql> select * from schema_index_statistics limit 5; +-- +------------------+-------------+------------+---------------+----------------+---------------+----------------+--------------+----------------+--------------+----------------+ +-- | table_schema | table_name | index_name | rows_selected | select_latency | rows_inserted | insert_latency | rows_updated | update_latency | rows_deleted | delete_latency | +-- +------------------+-------------+------------+---------------+----------------+---------------+----------------+--------------+----------------+--------------+----------------+ +-- | mem | mysqlserver | PRIMARY | 6208 | 108.27 ms | 0 | 0 ps | 5470 | 1.47 s | 0 | 0 ps | +-- | mem | innodb | PRIMARY | 4666 | 76.27 ms | 0 | 0 ps | 4454 | 571.47 ms | 0 | 0 ps | +-- | mem | connection | PRIMARY | 1064 | 20.98 ms | 0 | 0 ps | 1064 | 457.30 ms | 0 | 0 ps | +-- | mem | environment | PRIMARY | 5566 | 151.17 ms | 0 | 0 ps | 694 | 252.57 ms | 0 | 0 ps | +-- | mem | querycache | PRIMARY | 1698 | 27.99 ms | 0 | 0 ps | 1698 | 371.72 ms | 0 | 0 ps | +-- +------------------+-------------+------------+---------------+----------------+---------------+----------------+--------------+----------------+--------------+----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW schema_index_statistics ( + table_schema, + table_name, + index_name, + rows_selected, + select_latency, + rows_inserted, + insert_latency, + rows_updated, + update_latency, + rows_deleted, + delete_latency +) AS +SELECT OBJECT_SCHEMA AS table_schema, + OBJECT_NAME AS table_name, + INDEX_NAME as index_name, + COUNT_FETCH AS rows_selected, + sys.format_time(SUM_TIMER_FETCH) AS select_latency, + COUNT_INSERT AS rows_inserted, + sys.format_time(SUM_TIMER_INSERT) AS insert_latency, + COUNT_UPDATE AS rows_updated, + sys.format_time(SUM_TIMER_UPDATE) AS update_latency, + COUNT_DELETE AS rows_deleted, + sys.format_time(SUM_TIMER_INSERT) AS delete_latency + FROM performance_schema.table_io_waits_summary_by_index_usage + WHERE index_name IS NOT NULL + ORDER BY sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/schema_table_lock_waits.sql b/scripts/sys_schema/views/p_s/schema_table_lock_waits.sql new file mode 100644 index 00000000..dd293c5b --- /dev/null +++ b/scripts/sys_schema/views/p_s/schema_table_lock_waits.sql @@ -0,0 +1,97 @@ +-- Copyright (c) 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: schema_table_lock_waits +-- +-- Shows sessions that are blocked waiting on table metadata locks, and +-- who is blocking them. +-- +-- mysql> select * from sys.schema_table_lock_waits\G +-- *************************** 1. row *************************** +-- object_schema: test +-- object_name: t +-- waiting_thread_id: 43 +-- waiting_pid: 21 +-- waiting_account: msandbox@localhost +-- waiting_lock_type: SHARED_UPGRADABLE +-- waiting_lock_duration: TRANSACTION +-- waiting_query: alter table test.t add foo int +-- waiting_query_secs: 988 +-- waiting_query_rows_affected: 0 +-- waiting_query_rows_examined: 0 +-- blocking_thread_id: 42 +-- blocking_pid: 20 +-- blocking_account: msandbox@localhost +-- blocking_lock_type: SHARED_NO_READ_WRITE +-- blocking_lock_duration: TRANSACTION +-- sql_kill_blocking_query: KILL QUERY 20 +-- sql_kill_blocking_connection: KILL 20 +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW schema_table_lock_waits ( + object_schema, + object_name, + waiting_thread_id, + waiting_pid, + waiting_account, + waiting_lock_type, + waiting_lock_duration, + waiting_query, + waiting_query_secs, + waiting_query_rows_affected, + waiting_query_rows_examined, + blocking_thread_id, + blocking_pid, + blocking_account, + blocking_lock_type, + blocking_lock_duration, + sql_kill_blocking_query, + sql_kill_blocking_connection +) AS +SELECT g.object_schema AS object_schema, + g.object_name AS object_name, + pt.thread_id AS waiting_thread_id, + pt.processlist_id AS waiting_pid, + sys.ps_thread_account(p.owner_thread_id) AS waiting_account, + p.lock_type AS waiting_lock_type, + p.lock_duration AS waiting_lock_duration, + sys.format_statement(pt.processlist_info) AS waiting_query, + pt.processlist_time AS waiting_query_secs, + ps.rows_affected AS waiting_query_rows_affected, + ps.rows_examined AS waiting_query_rows_examined, + gt.thread_id AS blocking_thread_id, + gt.processlist_id AS blocking_pid, + sys.ps_thread_account(g.owner_thread_id) AS blocking_account, + g.lock_type AS blocking_lock_type, + g.lock_duration AS blocking_lock_duration, + CONCAT('KILL QUERY ', gt.processlist_id) AS sql_kill_blocking_query, + CONCAT('KILL ', gt.processlist_id) AS sql_kill_blocking_connection + FROM performance_schema.metadata_locks g + INNER JOIN performance_schema.metadata_locks p + ON g.object_type = p.object_type + AND g.object_schema = p.object_schema + AND g.object_name = p.object_name + AND g.lock_status = 'GRANTED' + AND p.lock_status = 'PENDING' + INNER JOIN performance_schema.threads gt ON g.owner_thread_id = gt.thread_id + INNER JOIN performance_schema.threads pt ON p.owner_thread_id = pt.thread_id + LEFT JOIN performance_schema.events_statements_current gs ON g.owner_thread_id = gs.thread_id + LEFT JOIN performance_schema.events_statements_current ps ON p.owner_thread_id = ps.thread_id + WHERE g.object_type = 'TABLE'; diff --git a/scripts/sys_schema/views/p_s/schema_table_statistics.sql b/scripts/sys_schema/views/p_s/schema_table_statistics.sql new file mode 100644 index 00000000..198d2e0e --- /dev/null +++ b/scripts/sys_schema/views/p_s/schema_table_statistics.sql @@ -0,0 +1,94 @@ +-- 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: schema_table_statistics +-- +-- Statistics around tables. +-- +-- Ordered by the total wait time descending - top tables are most contended. +-- +-- mysql> SELECT * FROM schema_table_statistics\G +-- *************************** 1. row *************************** +-- table_schema: sys +-- table_name: sys_config +-- total_latency: 0 ps +-- rows_fetched: 0 +-- fetch_latency: 0 ps +-- rows_inserted: 0 +-- insert_latency: 0 ps +-- rows_updated: 0 +-- update_latency: 0 ps +-- rows_deleted: 0 +-- delete_latency: 0 ps +-- io_read_requests: 8 +-- io_read: 2.28 KiB +-- io_read_latency: 727.32 us +-- io_write_requests: 0 +-- io_write: 0 bytes +-- io_write_latency: 0 ps +-- io_misc_requests: 10 +-- io_misc_latency: 126.88 us +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW schema_table_statistics ( + table_schema, + table_name, + total_latency, + rows_fetched, + fetch_latency, + rows_inserted, + insert_latency, + rows_updated, + update_latency, + rows_deleted, + delete_latency, + io_read_requests, + io_read, + io_read_latency, + io_write_requests, + io_write, + io_write_latency, + io_misc_requests, + io_misc_latency +) AS +SELECT pst.object_schema AS table_schema, + pst.object_name AS table_name, + sys.format_time(pst.sum_timer_wait) AS total_latency, + pst.count_fetch AS rows_fetched, + sys.format_time(pst.sum_timer_fetch) AS fetch_latency, + pst.count_insert AS rows_inserted, + sys.format_time(pst.sum_timer_insert) AS insert_latency, + pst.count_update AS rows_updated, + sys.format_time(pst.sum_timer_update) AS update_latency, + pst.count_delete AS rows_deleted, + sys.format_time(pst.sum_timer_delete) AS delete_latency, + fsbi.count_read AS io_read_requests, + sys.format_bytes(fsbi.sum_number_of_bytes_read) AS io_read, + sys.format_time(fsbi.sum_timer_read) AS io_read_latency, + fsbi.count_write AS io_write_requests, + sys.format_bytes(fsbi.sum_number_of_bytes_write) AS io_write, + sys.format_time(fsbi.sum_timer_write) AS io_write_latency, + fsbi.count_misc AS io_misc_requests, + sys.format_time(fsbi.sum_timer_misc) AS io_misc_latency + FROM performance_schema.table_io_waits_summary_by_table AS pst + LEFT JOIN x$ps_schema_table_statistics_io AS fsbi + ON pst.object_schema = fsbi.table_schema + AND pst.object_name = fsbi.table_name + ORDER BY pst.sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/schema_table_statistics_with_buffer.sql b/scripts/sys_schema/views/p_s/schema_table_statistics_with_buffer.sql new file mode 100644 index 00000000..acdaefb3 --- /dev/null +++ b/scripts/sys_schema/views/p_s/schema_table_statistics_with_buffer.sql @@ -0,0 +1,122 @@ +-- 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: schema_table_statistics_with_buffer +-- +-- Statistics around tables. +-- +-- Ordered by the total wait time descending - top tables are most contended. +-- +-- More statistics such as caching stats for the InnoDB buffer pool with InnoDB tables +-- +-- mysql> select * from schema_table_statistics_with_buffer limit 1\G +-- *************************** 1. row *************************** +-- table_schema: mem +-- table_name: mysqlserver +-- rows_fetched: 27087 +-- fetch_latency: 442.72 ms +-- rows_inserted: 2 +-- insert_latency: 185.04 us +-- rows_updated: 5096 +-- update_latency: 1.39 s +-- rows_deleted: 0 +-- delete_latency: 0 ps +-- io_read_requests: 2565 +-- io_read_bytes: 1121627 +-- io_read_latency: 10.07 ms +-- io_write_requests: 1691 +-- io_write_bytes: 128383 +-- io_write_latency: 14.17 ms +-- io_misc_requests: 2698 +-- io_misc_latency: 433.66 ms +-- innodb_buffer_pages: 19 +-- innodb_buffer_pages_hashed: 19 +-- innodb_buffer_pages_old: 19 +-- innodb_buffer_bytes_allocated: 311296 +-- innodb_buffer_bytes_data: 1924 +-- innodb_buffer_rows_cached: 2 +-- + +DELIMITER $$ +BEGIN NOT ATOMIC +DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN END; +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW schema_table_statistics_with_buffer ( + table_schema, + table_name, + rows_fetched, + fetch_latency, + rows_inserted, + insert_latency, + rows_updated, + update_latency, + rows_deleted, + delete_latency, + io_read_requests, + io_read, + io_read_latency, + io_write_requests, + io_write, + io_write_latency, + io_misc_requests, + io_misc_latency, + innodb_buffer_allocated, + innodb_buffer_data, + innodb_buffer_free, + innodb_buffer_pages, + innodb_buffer_pages_hashed, + innodb_buffer_pages_old, + innodb_buffer_rows_cached +) AS +SELECT pst.object_schema AS table_schema, + pst.object_name AS table_name, + pst.count_fetch AS rows_fetched, + sys.format_time(pst.sum_timer_fetch) AS fetch_latency, + pst.count_insert AS rows_inserted, + sys.format_time(pst.sum_timer_insert) AS insert_latency, + pst.count_update AS rows_updated, + sys.format_time(pst.sum_timer_update) AS update_latency, + pst.count_delete AS rows_deleted, + sys.format_time(pst.sum_timer_delete) AS delete_latency, + fsbi.count_read AS io_read_requests, + sys.format_bytes(fsbi.sum_number_of_bytes_read) AS io_read, + sys.format_time(fsbi.sum_timer_read) AS io_read_latency, + fsbi.count_write AS io_write_requests, + sys.format_bytes(fsbi.sum_number_of_bytes_write) AS io_write, + sys.format_time(fsbi.sum_timer_write) AS io_write_latency, + fsbi.count_misc AS io_misc_requests, + sys.format_time(fsbi.sum_timer_misc) AS io_misc_latency, + sys.format_bytes(ibp.allocated) AS innodb_buffer_allocated, + sys.format_bytes(ibp.data) AS innodb_buffer_data, + sys.format_bytes(ibp.allocated - ibp.data) AS innodb_buffer_free, + ibp.pages AS innodb_buffer_pages, + ibp.pages_hashed AS innodb_buffer_pages_hashed, + ibp.pages_old AS innodb_buffer_pages_old, + ibp.rows_cached AS innodb_buffer_rows_cached + FROM performance_schema.table_io_waits_summary_by_table AS pst + LEFT JOIN x$ps_schema_table_statistics_io AS fsbi + ON pst.object_schema = fsbi.table_schema + AND pst.object_name = fsbi.table_name + LEFT JOIN sys.x$innodb_buffer_stats_by_table AS ibp + ON pst.object_schema = ibp.object_schema + AND pst.object_name = ibp.object_name + ORDER BY pst.sum_timer_wait DESC; + +END$$ +DELIMITER ; diff --git a/scripts/sys_schema/views/p_s/schema_tables_with_full_table_scans.sql b/scripts/sys_schema/views/p_s/schema_tables_with_full_table_scans.sql new file mode 100644 index 00000000..6199d244 --- /dev/null +++ b/scripts/sys_schema/views/p_s/schema_tables_with_full_table_scans.sql @@ -0,0 +1,51 @@ +-- 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: schema_tables_with_full_table_scans +-- +-- Find tables that are being accessed by full table scans +-- ordering by the number of rows scanned descending. +-- +-- mysql> select * from schema_tables_with_full_table_scans limit 5; +-- +--------------------+--------------------------------+-------------------+-----------+ +-- | object_schema | object_name | rows_full_scanned | latency | +-- +--------------------+--------------------------------+-------------------+-----------+ +-- | mem30__instruments | fsstatistics | 10207042 | 13.10 s | +-- | mem30__instruments | preparedstatementapidata | 436428 | 973.27 ms | +-- | mem30__instruments | mysqlprocessactivity | 411702 | 282.07 ms | +-- | mem30__instruments | querycachequeriesincachedata | 374011 | 767.15 ms | +-- | mem30__instruments | rowaccessesdata | 322321 | 1.55 s | +-- +--------------------+--------------------------------+-------------------+-----------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW schema_tables_with_full_table_scans ( + object_schema, + object_name, + rows_full_scanned, + latency +) AS +SELECT object_schema, + object_name, + count_read AS rows_full_scanned, + sys.format_time(sum_timer_wait) AS latency + FROM performance_schema.table_io_waits_summary_by_index_usage + WHERE index_name IS NULL + AND count_read > 0 + ORDER BY count_read DESC; diff --git a/scripts/sys_schema/views/p_s/schema_unused_indexes.sql b/scripts/sys_schema/views/p_s/schema_unused_indexes.sql new file mode 100644 index 00000000..168f88bb --- /dev/null +++ b/scripts/sys_schema/views/p_s/schema_unused_indexes.sql @@ -0,0 +1,56 @@ +-- 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: schema_unused_indexes +-- +-- Finds indexes that have had no events against them (and hence, no usage). +-- +-- To trust whether the data from this view is representative of your workload, +-- you should ensure that the server has been up for a representative amount of +-- time before using it. +-- +-- PRIMARY (key) indexes are ignored. +-- +-- mysql> select * from schema_unused_indexes limit 5; +-- +--------------------+---------------------+--------------------+ +-- | object_schema | object_name | index_name | +-- +--------------------+---------------------+--------------------+ +-- | mem30__bean_config | plists | path | +-- | mem30__config | group_selections | name | +-- | mem30__config | notification_groups | name | +-- | mem30__config | user_form_defaults | FKC1AEF1F9E7EE2CFB | +-- | mem30__enterprise | whats_new_entries | entryId | +-- +--------------------+---------------------+--------------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW schema_unused_indexes ( + object_schema, + object_name, + index_name +) AS +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' + AND index_name != 'PRIMARY' + ORDER BY object_schema, object_name; diff --git a/scripts/sys_schema/views/p_s/session_ssl_status.sql b/scripts/sys_schema/views/p_s/session_ssl_status.sql new file mode 100644 index 00000000..cb8ce855 --- /dev/null +++ b/scripts/sys_schema/views/p_s/session_ssl_status.sql @@ -0,0 +1,36 @@ +-- +-- View: session_ssl_status +-- +-- Shows SSL version, cipher and the count of re-used SSL sessions per connection +-- +-- mysql> select * from session_ssl_status; +-- +-----------+-------------+--------------------+---------------------+ +-- | thread_id | ssl_version | ssl_cipher | ssl_sessions_reused | +-- +-----------+-------------+--------------------+---------------------+ +-- | 26 | TLSv1 | DHE-RSA-AES256-SHA | 0 | +-- | 27 | TLSv1 | DHE-RSA-AES256-SHA | 0 | +-- | 28 | TLSv1 | DHE-RSA-AES256-SHA | 0 | +-- +-----------+-------------+--------------------+---------------------+ +-- 3 rows in set (0.00 sec) +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW session_ssl_status ( + thread_id, + ssl_version, + ssl_cipher, + ssl_sessions_reused +) AS +SELECT sslver.thread_id, + sslver.variable_value ssl_version, + sslcip.variable_value ssl_cipher, + sslreuse.variable_value ssl_sessions_reused + FROM performance_schema.status_by_thread sslver + LEFT JOIN performance_schema.status_by_thread sslcip + ON (sslcip.thread_id=sslver.thread_id and sslcip.variable_name='Ssl_cipher') + LEFT JOIN performance_schema.status_by_thread sslreuse + ON (sslreuse.thread_id=sslver.thread_id and sslreuse.variable_name='Ssl_sessions_reused') + WHERE sslver.variable_name='Ssl_version'; diff --git a/scripts/sys_schema/views/p_s/sessions.sql b/scripts/sys_schema/views/p_s/sessions.sql new file mode 100644 index 00000000..94471aab --- /dev/null +++ b/scripts/sys_schema/views/p_s/sessions.sql @@ -0,0 +1,64 @@ +-- 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: session +-- +-- Filter sys.processlist to only show user sessions and not background threads. +-- This is a non-blocking closer replacement to +-- [INFORMATION_SCHEMA. | SHOW FULL] PROCESSLIST +-- +-- Performs less locking than the legacy sources, whilst giving extra information. +-- +-- mysql> select * from sys.session\G +-- *************************** 1. row *************************** +-- thd_id: 24 +-- conn_id: 2 +-- user: root@localhost +-- db: sys +-- command: Query +-- state: Sending data +-- time: 0 +-- current_statement: select * from sys.session +-- statement_latency: 137.22 ms +-- progress: NULL +-- lock_latency: 33.75 ms +-- rows_examined: 0 +-- rows_sent: 0 +-- rows_affected: 0 +-- tmp_tables: 4 +-- tmp_disk_tables: 1 +-- full_scan: YES +-- last_statement: NULL +-- last_statement_latency: NULL +-- current_memory: 3.26 MiB +-- last_wait: wait/synch/mutex/innodb/file_format_max_mutex +-- last_wait_latency: 64.09 ns +-- source: trx0sys.cc:778 +-- trx_latency: 7.88 s +-- trx_state: ACTIVE +-- trx_autocommit: NO +-- pid: 4212 +-- program_name: mysql +-- + +CREATE OR REPLACE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW session + AS +SELECT * FROM sys.processlist +WHERE conn_id IS NOT NULL AND command != 'Daemon'; + diff --git a/scripts/sys_schema/views/p_s/statement_analysis.sql b/scripts/sys_schema/views/p_s/statement_analysis.sql new file mode 100644 index 00000000..0d9c9cef --- /dev/null +++ b/scripts/sys_schema/views/p_s/statement_analysis.sql @@ -0,0 +1,103 @@ +-- 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: statement_analysis +-- +-- Lists a normalized statement view with aggregated statistics, +-- mimics the MySQL Enterprise Monitor Query Analysis view, +-- ordered by the total execution time per normalized statement +-- +-- mysql> select- * from statement_analysis limit 1\G +-- *************************** 1. row--************************** +-- query: SELECT * FROM `schema_object_o ... MA` , `information_schema` ... +-- db: sys +-- full_scan: * +-- exec_count: 2 +-- err_count: 0 +-- warn_count: 0 +-- total_latency: 16.75 s +-- max_latency: 16.57 s +-- avg_latency: 8.38 s +-- lock_latency: 16.69 s +-- rows_sent: 84 +-- rows_sent_avg: 42 +-- rows_examined: 20012 +-- rows_affected: 0 +-- rows_affected_avg: 0 +-- rows_examined_avg: 10006 +-- tmp_tables: 378 +-- tmp_disk_tables: 66 +-- rows_sorted: 168 +-- sort_merge_passes: 0 +-- digest: 54f9bd520f0bbf15db0c2ed93386bec9 +-- first_seen: 2014-03-07 13:13:41 +-- last_seen: 2014-03-07 13:13:48 +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW statement_analysis ( + query, + db, + full_scan, + exec_count, + err_count, + warn_count, + total_latency, + max_latency, + avg_latency, + lock_latency, + rows_sent, + rows_sent_avg, + rows_examined, + rows_examined_avg, + rows_affected, + rows_affected_avg, + tmp_tables, + tmp_disk_tables, + rows_sorted, + sort_merge_passes, + digest, + first_seen, + last_seen +) AS +SELECT sys.format_statement(DIGEST_TEXT) AS query, + SCHEMA_NAME AS db, + IF(SUM_NO_GOOD_INDEX_USED > 0 OR SUM_NO_INDEX_USED > 0, '*', '') AS full_scan, + COUNT_STAR AS exec_count, + SUM_ERRORS AS err_count, + SUM_WARNINGS AS warn_count, + sys.format_time(SUM_TIMER_WAIT) AS total_latency, + sys.format_time(MAX_TIMER_WAIT) AS max_latency, + sys.format_time(AVG_TIMER_WAIT) AS avg_latency, + sys.format_time(SUM_LOCK_TIME) AS lock_latency, + SUM_ROWS_SENT AS rows_sent, + ROUND(IFNULL(SUM_ROWS_SENT / NULLIF(COUNT_STAR, 0), 0)) AS rows_sent_avg, + SUM_ROWS_EXAMINED AS rows_examined, + ROUND(IFNULL(SUM_ROWS_EXAMINED / NULLIF(COUNT_STAR, 0), 0)) AS rows_examined_avg, + SUM_ROWS_AFFECTED AS rows_affected, + ROUND(IFNULL(SUM_ROWS_AFFECTED / NULLIF(COUNT_STAR, 0), 0)) AS rows_affected_avg, + SUM_CREATED_TMP_TABLES AS tmp_tables, + SUM_CREATED_TMP_DISK_TABLES AS tmp_disk_tables, + SUM_SORT_ROWS AS rows_sorted, + SUM_SORT_MERGE_PASSES AS sort_merge_passes, + DIGEST AS digest, + FIRST_SEEN AS first_seen, + LAST_SEEN as last_seen + FROM performance_schema.events_statements_summary_by_digest +ORDER BY SUM_TIMER_WAIT DESC; diff --git a/scripts/sys_schema/views/p_s/statements_with_errors_or_warnings.sql b/scripts/sys_schema/views/p_s/statements_with_errors_or_warnings.sql new file mode 100644 index 00000000..e5e5e67c --- /dev/null +++ b/scripts/sys_schema/views/p_s/statements_with_errors_or_warnings.sql @@ -0,0 +1,64 @@ +-- 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_errors_or_warnings +-- +-- Lists all normalized statements that have raised errors or warnings. +-- +-- mysql> select * from statements_with_errors_or_warnings LIMIT 1\G +-- *************************** 1. row *************************** +-- query: CREATE OR REPLACE ALGORITHM = ... _delete` AS `rows_deleted` ... +-- db: sys +-- exec_count: 2 +-- errors: 1 +-- error_pct: 50.0000 +-- warnings: 0 +-- warning_pct: 0.0000 +-- first_seen: 2014-03-07 12:56:54 +-- last_seen: 2014-03-07 13:01:01 +-- digest: 943a788859e623d5f7798ba0ae0fd8a9 +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW statements_with_errors_or_warnings ( + query, + db, + exec_count, + errors, + error_pct, + warnings, + warning_pct, + first_seen, + last_seen, + digest +) AS +SELECT sys.format_statement(DIGEST_TEXT) AS query, + SCHEMA_NAME as db, + COUNT_STAR AS exec_count, + SUM_ERRORS AS errors, + IFNULL(SUM_ERRORS / NULLIF(COUNT_STAR, 0), 0) * 100 as error_pct, + SUM_WARNINGS AS warnings, + IFNULL(SUM_WARNINGS / NULLIF(COUNT_STAR, 0), 0) * 100 as warning_pct, + FIRST_SEEN as first_seen, + LAST_SEEN as last_seen, + DIGEST AS digest + FROM performance_schema.events_statements_summary_by_digest + WHERE SUM_ERRORS > 0 + OR SUM_WARNINGS > 0 +ORDER BY SUM_ERRORS DESC, SUM_WARNINGS DESC; diff --git a/scripts/sys_schema/views/p_s/statements_with_full_table_scans.sql b/scripts/sys_schema/views/p_s/statements_with_full_table_scans.sql new file mode 100644 index 00000000..84217364 --- /dev/null +++ b/scripts/sys_schema/views/p_s/statements_with_full_table_scans.sql @@ -0,0 +1,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, + sys.format_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; diff --git a/scripts/sys_schema/views/p_s/statements_with_runtimes_in_95th_percentile.sql b/scripts/sys_schema/views/p_s/statements_with_runtimes_in_95th_percentile.sql new file mode 100644 index 00000000..6e2489ed --- /dev/null +++ b/scripts/sys_schema/views/p_s/statements_with_runtimes_in_95th_percentile.sql @@ -0,0 +1,74 @@ +-- 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_runtimes_in_95th_percentile +-- +-- List all statements whose average runtime, in microseconds, is in the top 95th percentile. +-- +-- mysql> select * from statements_with_runtimes_in_95th_percentile limit 5; +-- +-------------------------------------------------------------------+------+-----------+------------+-----------+------------+---------------+-------------+-------------+-----------+---------------+---------------+-------------------+---------------------+---------------------+----------------------------------+ +-- | query | db | full_scan | exec_count | err_count | warn_count | total_latency | max_latency | avg_latency | rows_sent | rows_sent_avg | rows_examined | rows_examined_avg | FIRST_SEEN | LAST_SEEN | digest | +-- +-------------------------------------------------------------------+------+-----------+------------+-----------+------------+---------------+-------------+-------------+-----------+---------------+---------------+-------------------+---------------------+---------------------+----------------------------------+ +-- | SELECT `e` . `round_robin_bin` ... `timestamp` = `maxes` . `ts` | mem | * | 14 | 0 | 0 | 43.96 s | 6.69 s | 3.14 s | 11 | 1 | 253170 | 18084 | 2013-12-04 20:05:01 | 2013-12-04 20:06:34 | 29ba002bf039bb6439357a10134407de | +-- | SELECT `e` . `round_robin_bin` ... `timestamp` = `maxes` . `ts` | mem | * | 8 | 0 | 0 | 17.89 s | 4.12 s | 2.24 s | 7 | 1 | 169534 | 21192 | 2013-12-04 20:04:54 | 2013-12-04 20:05:05 | 0b1c1f91e7e9e0ff91aa49d15f540793 | +-- | SELECT `e` . `round_robin_bin` ... `timestamp` = `maxes` . `ts` | mem | * | 1 | 0 | 0 | 2.22 s | 2.22 s | 2.22 s | 1 | 1 | 40322 | 40322 | 2013-12-04 20:05:39 | 2013-12-04 20:05:39 | 07b27145c8f8a3779737df5032374833 | +-- | SELECT `e` . `round_robin_bin` ... `timestamp` = `maxes` . `ts` | mem | * | 1 | 0 | 0 | 1.97 s | 1.97 s | 1.97 s | 1 | 1 | 40322 | 40322 | 2013-12-04 20:05:39 | 2013-12-04 20:05:39 | a07488137ea5c1bccf3e291c50bfd21f | +-- | SELECT `e` . `round_robin_bin` ... `timestamp` = `maxes` . `ts` | mem | * | 2 | 0 | 0 | 3.91 s | 3.91 s | 1.96 s | 1 | 1 | 13126 | 6563 | 2013-12-04 20:05:04 | 2013-12-04 20:06:34 | b8bddc6566366dafc7e474f67096a93b | +-- +-------------------------------------------------------------------+------+-----------+------------+-----------+------------+---------------+-------------+-------------+-----------+---------------+---------------+-------------------+---------------------+---------------------+----------------------------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW statements_with_runtimes_in_95th_percentile ( + query, + db, + full_scan, + exec_count, + err_count, + warn_count, + total_latency, + max_latency, + avg_latency, + rows_sent, + rows_sent_avg, + rows_examined, + rows_examined_avg, + first_seen, + last_seen, + digest +) AS +SELECT sys.format_statement(DIGEST_TEXT) AS query, + SCHEMA_NAME as db, + IF(SUM_NO_GOOD_INDEX_USED > 0 OR SUM_NO_INDEX_USED > 0, '*', '') AS full_scan, + COUNT_STAR AS exec_count, + SUM_ERRORS AS err_count, + SUM_WARNINGS AS warn_count, + sys.format_time(SUM_TIMER_WAIT) AS total_latency, + sys.format_time(MAX_TIMER_WAIT) AS max_latency, + sys.format_time(AVG_TIMER_WAIT) AS avg_latency, + SUM_ROWS_SENT AS rows_sent, + ROUND(IFNULL(SUM_ROWS_SENT / NULLIF(COUNT_STAR, 0), 0)) AS rows_sent_avg, + SUM_ROWS_EXAMINED AS rows_examined, + ROUND(IFNULL(SUM_ROWS_EXAMINED / NULLIF(COUNT_STAR, 0), 0)) 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 stmts + JOIN sys.x$ps_digest_95th_percentile_by_avg_us AS top_percentile + ON ROUND(stmts.avg_timer_wait/1000000) >= top_percentile.avg_us + ORDER BY AVG_TIMER_WAIT DESC; diff --git a/scripts/sys_schema/views/p_s/statements_with_sorting.sql b/scripts/sys_schema/views/p_s/statements_with_sorting.sql new file mode 100644 index 00000000..0216a12e --- /dev/null +++ b/scripts/sys_schema/views/p_s/statements_with_sorting.sql @@ -0,0 +1,73 @@ +-- 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_sorting +-- +-- Lists all normalized statements that have done sorts, +-- ordered by total_latency descending. +-- +-- mysql> select * from statements_with_sorting limit 1\G +-- *************************** 1. row *************************** +-- query: SELECT * FROM `schema_object_o ... MA` , `information_schema` ... +-- db: sys +-- exec_count: 2 +-- total_latency: 16.75 s +-- sort_merge_passes: 0 +-- avg_sort_merges: 0 +-- sorts_using_scans: 12 +-- sort_using_range: 0 +-- rows_sorted: 168 +-- avg_rows_sorted: 84 +-- first_seen: 2014-03-07 13:13:41 +-- last_seen: 2014-03-07 13:13:48 +-- digest: 54f9bd520f0bbf15db0c2ed93386bec9 +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW statements_with_sorting ( + query, + db, + exec_count, + total_latency, + sort_merge_passes, + avg_sort_merges, + sorts_using_scans, + sort_using_range, + rows_sorted, + avg_rows_sorted, + first_seen, + last_seen, + digest +) AS +SELECT sys.format_statement(DIGEST_TEXT) AS query, + SCHEMA_NAME db, + COUNT_STAR AS exec_count, + sys.format_time(SUM_TIMER_WAIT) AS total_latency, + SUM_SORT_MERGE_PASSES AS sort_merge_passes, + ROUND(IFNULL(SUM_SORT_MERGE_PASSES / NULLIF(COUNT_STAR, 0), 0)) AS avg_sort_merges, + SUM_SORT_SCAN AS sorts_using_scans, + SUM_SORT_RANGE AS sort_using_range, + SUM_SORT_ROWS AS rows_sorted, + ROUND(IFNULL(SUM_SORT_ROWS / NULLIF(COUNT_STAR, 0), 0)) AS avg_rows_sorted, + FIRST_SEEN as first_seen, + LAST_SEEN as last_seen, + DIGEST AS digest + FROM performance_schema.events_statements_summary_by_digest + WHERE SUM_SORT_ROWS > 0 + ORDER BY SUM_TIMER_WAIT DESC; diff --git a/scripts/sys_schema/views/p_s/statements_with_temp_tables.sql b/scripts/sys_schema/views/p_s/statements_with_temp_tables.sql new file mode 100644 index 00000000..3f9dfbc6 --- /dev/null +++ b/scripts/sys_schema/views/p_s/statements_with_temp_tables.sql @@ -0,0 +1,68 @@ +-- 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_temp_tables +-- +-- Lists all normalized statements that use temporary tables +-- ordered by number of on disk temporary tables descending first, +-- then by the number of memory tables. +-- +-- mysql> select * from statements_with_temp_tables limit 1\G +-- *************************** 1. row *************************** +-- query: SELECT * FROM `schema_object_o ... MA` , `information_schema` ... +-- db: sys +-- exec_count: 2 +-- total_latency: 16.75 s +-- memory_tmp_tables: 378 +-- disk_tmp_tables: 66 +-- avg_tmp_tables_per_query: 189 +-- tmp_tables_to_disk_pct: 17 +-- first_seen: 2014-03-07 13:13:41 +-- last_seen: 2014-03-07 13:13:48 +-- digest: 54f9bd520f0bbf15db0c2ed93386bec9 +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW statements_with_temp_tables ( + query, + db, + exec_count, + total_latency, + memory_tmp_tables, + disk_tmp_tables, + avg_tmp_tables_per_query, + tmp_tables_to_disk_pct, + first_seen, + last_seen, + digest +) AS +SELECT sys.format_statement(DIGEST_TEXT) AS query, + SCHEMA_NAME as db, + COUNT_STAR AS exec_count, + sys.format_time(SUM_TIMER_WAIT) as total_latency, + SUM_CREATED_TMP_TABLES AS memory_tmp_tables, + SUM_CREATED_TMP_DISK_TABLES AS disk_tmp_tables, + ROUND(IFNULL(SUM_CREATED_TMP_TABLES / NULLIF(COUNT_STAR, 0), 0)) AS avg_tmp_tables_per_query, + ROUND(IFNULL(SUM_CREATED_TMP_DISK_TABLES / NULLIF(SUM_CREATED_TMP_TABLES, 0), 0) * 100) AS tmp_tables_to_disk_pct, + FIRST_SEEN as first_seen, + LAST_SEEN as last_seen, + DIGEST AS digest + FROM performance_schema.events_statements_summary_by_digest + WHERE SUM_CREATED_TMP_TABLES > 0 +ORDER BY SUM_CREATED_TMP_DISK_TABLES DESC, SUM_CREATED_TMP_TABLES DESC; diff --git a/scripts/sys_schema/views/p_s/user_summary.sql b/scripts/sys_schema/views/p_s/user_summary.sql new file mode 100644 index 00000000..85f08878 --- /dev/null +++ b/scripts/sys_schema/views/p_s/user_summary.sql @@ -0,0 +1,60 @@ +-- 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: user_summary +-- +-- Summarizes statement activity, file IO and connections by user. +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from user_summary; +-- +------+------------+-------------------+-----------------------+-------------+----------+-----------------+---------------------+-------------------+--------------+ +-- | user | statements | statement_latency | statement_avg_latency | table_scans | file_ios | file_io_latency | current_connections | total_connections | unique_hosts | +-- +------+------------+-------------------+-----------------------+-------------+----------+-----------------+---------------------+-------------------+--------------+ +-- | root | 2924 | 00:03:59.53 | 81.92 ms | 82 | 54702 | 55.61 s | 1 | 1 | 1 | +-- +------+------------+-------------------+-----------------------+-------------+----------+-----------------+---------------------+-------------------+--------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW user_summary ( + user, + statements, + statement_latency, + statement_avg_latency, + table_scans, + file_ios, + file_io_latency, + current_connections, + total_connections, + unique_hosts +) AS +SELECT IF(accounts.user IS NULL, 'background', accounts.user) AS user, + SUM(stmt.total) AS statements, + sys.format_time(SUM(stmt.total_latency)) AS statement_latency, + sys.format_time(IFNULL(SUM(stmt.total_latency) / NULLIF(SUM(stmt.total), 0), 0)) AS statement_avg_latency, + SUM(stmt.full_scans) AS table_scans, + SUM(io.ios) AS file_ios, + sys.format_time(SUM(io.io_latency)) AS file_io_latency, + SUM(accounts.current_connections) AS current_connections, + SUM(accounts.total_connections) AS total_connections, + COUNT(DISTINCT host) AS unique_hosts + FROM performance_schema.accounts + LEFT JOIN sys.x$user_summary_by_statement_latency AS stmt ON IF(accounts.user IS NULL, 'background', accounts.user) = stmt.user + LEFT JOIN sys.x$user_summary_by_file_io AS io ON IF(accounts.user IS NULL, 'background', accounts.user) = io.user + GROUP BY IF(accounts.user IS NULL, 'background', accounts.user); diff --git a/scripts/sys_schema/views/p_s/user_summary_57.sql b/scripts/sys_schema/views/p_s/user_summary_57.sql new file mode 100644 index 00000000..a3147a17 --- /dev/null +++ b/scripts/sys_schema/views/p_s/user_summary_57.sql @@ -0,0 +1,67 @@ +-- 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: user_summary +-- +-- Summarizes statement activity and connections by user +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from user_summary; +-- +------+------------+---------------+-------------+---------------------+-------------------+--------------+----------------+------------------------+ +-- | user | statements | total_latency | avg_latency | current_connections | total_connections | unique_hosts | current_memory | total_memory_allocated | +-- +------+------------+---------------+-------------+---------------------+-------------------+--------------+----------------+------------------------+ +-- | root | 5663 | 00:01:47.14 | 18.92 ms | 1 | 1 | 1 | 1.41 MiB | 543.55 MiB | +-- | mark | 225 | 14.49 s | 64.40 ms | 1 | 1 | 1 | 707.60 KiB | 81.02 MiB | +-- +------+------------+---------------+-------------+---------------------+-------------------+--------------+----------------+------------------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW user_summary ( + user, + statements, + statement_latency, + statement_avg_latency, + table_scans, + file_ios, + file_io_latency, + current_connections, + total_connections, + unique_hosts, + current_memory, + total_memory_allocated +) AS +SELECT IF(accounts.user IS NULL, 'background', accounts.user) AS user, + SUM(stmt.total) AS statements, + sys.format_time(SUM(stmt.total_latency)) AS statement_latency, + sys.format_time(IFNULL(SUM(stmt.total_latency) / NULLIF(SUM(stmt.total), 0), 0)) AS statement_avg_latency, + SUM(stmt.full_scans) AS table_scans, + SUM(io.ios) AS file_ios, + sys.format_time(SUM(io.io_latency)) AS file_io_latency, + SUM(accounts.current_connections) AS current_connections, + SUM(accounts.total_connections) AS total_connections, + COUNT(DISTINCT host) AS unique_hosts, + sys.format_bytes(SUM(mem.current_allocated)) AS current_memory, + sys.format_bytes(SUM(mem.total_allocated)) AS total_memory_allocated + FROM performance_schema.accounts + LEFT JOIN sys.x$user_summary_by_statement_latency AS stmt ON IF(accounts.user IS NULL, 'background', accounts.user) = stmt.user + LEFT JOIN sys.x$user_summary_by_file_io AS io ON IF(accounts.user IS NULL, 'background', accounts.user) = io.user + LEFT JOIN sys.x$memory_by_user_by_current_bytes mem ON IF(accounts.user IS NULL, 'background', accounts.user) = mem.user + GROUP BY IF(accounts.user IS NULL, 'background', accounts.user) + ORDER BY SUM(stmt.total_latency) DESC; diff --git a/scripts/sys_schema/views/p_s/user_summary_by_file_io.sql b/scripts/sys_schema/views/p_s/user_summary_by_file_io.sql new file mode 100644 index 00000000..85862d50 --- /dev/null +++ b/scripts/sys_schema/views/p_s/user_summary_by_file_io.sql @@ -0,0 +1,47 @@ +-- 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: user_summary_by_file_io +-- +-- Summarizes file IO totals per user. +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from user_summary_by_file_io; +-- +------------+-------+------------+ +-- | user | ios | io_latency | +-- +------------+-------+------------+ +-- | root | 26457 | 21.58 s | +-- | background | 1189 | 394.21 ms | +-- +------------+-------+------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW user_summary_by_file_io ( + user, + ios, + io_latency +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + SUM(count_star) AS ios, + sys.format_time(SUM(sum_timer_wait)) AS io_latency + FROM performance_schema.events_waits_summary_by_user_by_event_name + WHERE event_name LIKE 'wait/io/file/%' + GROUP BY IF(user IS NULL, 'background', user) + ORDER BY SUM(sum_timer_wait) DESC; diff --git a/scripts/sys_schema/views/p_s/user_summary_by_file_io_type.sql b/scripts/sys_schema/views/p_s/user_summary_by_file_io_type.sql new file mode 100644 index 00000000..37b4b14b --- /dev/null +++ b/scripts/sys_schema/views/p_s/user_summary_by_file_io_type.sql @@ -0,0 +1,66 @@ +-- 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: user_summary_by_file_io_type +-- +-- Summarizes file IO by event type per user. +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from user_summary_by_file_io_type; +-- +------------+--------------------------------------+-------+-----------+-------------+ +-- | user | event_name | total | latency | max_latency | +-- +------------+--------------------------------------+-------+-----------+-------------+ +-- | background | wait/io/file/sql/FRM | 871 | 168.15 ms | 18.48 ms | +-- | background | wait/io/file/innodb/innodb_data_file | 173 | 129.56 ms | 34.09 ms | +-- | background | wait/io/file/innodb/innodb_log_file | 20 | 77.53 ms | 60.66 ms | +-- | background | wait/io/file/myisam/dfile | 40 | 6.54 ms | 4.58 ms | +-- | background | wait/io/file/mysys/charset | 3 | 4.79 ms | 4.71 ms | +-- | background | wait/io/file/myisam/kfile | 67 | 4.38 ms | 300.04 us | +-- | background | wait/io/file/sql/ERRMSG | 5 | 2.72 ms | 1.69 ms | +-- | background | wait/io/file/sql/pid | 3 | 266.30 us | 185.47 us | +-- | background | wait/io/file/sql/casetest | 5 | 246.81 us | 150.19 us | +-- | background | wait/io/file/sql/global_ddl_log | 2 | 21.24 us | 18.59 us | +-- | root | wait/io/file/sql/file_parser | 1422 | 4.80 s | 135.14 ms | +-- | root | wait/io/file/sql/FRM | 865 | 85.82 ms | 9.81 ms | +-- | root | wait/io/file/myisam/kfile | 1073 | 37.14 ms | 15.79 ms | +-- | root | wait/io/file/myisam/dfile | 2991 | 25.53 ms | 5.25 ms | +-- | root | wait/io/file/sql/dbopt | 20 | 1.07 ms | 153.07 us | +-- | root | wait/io/file/sql/misc | 4 | 59.71 us | 33.75 us | +-- | root | wait/io/file/archive/data | 1 | 13.91 us | 13.91 us | +-- +------------+--------------------------------------+-------+-----------+-------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW user_summary_by_file_io_type ( + user, + event_name, + total, + latency, + max_latency +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + event_name, + count_star AS total, + sys.format_time(sum_timer_wait) AS latency, + sys.format_time(max_timer_wait) AS max_latency + FROM performance_schema.events_waits_summary_by_user_by_event_name + WHERE event_name LIKE 'wait/io/file%' + AND count_star > 0 + ORDER BY user, sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/user_summary_by_stages.sql b/scripts/sys_schema/views/p_s/user_summary_by_stages.sql new file mode 100644 index 00000000..ab34a3ee --- /dev/null +++ b/scripts/sys_schema/views/p_s/user_summary_by_stages.sql @@ -0,0 +1,64 @@ +-- 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: user_summary_by_stages +-- +-- Summarizes stages by user, ordered by user and total latency per stage. +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from user_summary_by_stages; +-- +------+--------------------------------+-------+---------------+-------------+ +-- | user | event_name | total | total_latency | avg_latency | +-- +------+--------------------------------+-------+---------------+-------------+ +-- | root | stage/sql/Opening tables | 889 | 1.97 ms | 2.22 us | +-- | root | stage/sql/Creating sort index | 4 | 1.79 ms | 446.30 us | +-- | root | stage/sql/init | 10 | 312.27 us | 31.23 us | +-- | root | stage/sql/checking permissions | 10 | 300.62 us | 30.06 us | +-- | root | stage/sql/freeing items | 5 | 85.89 us | 17.18 us | +-- | root | stage/sql/statistics | 5 | 79.15 us | 15.83 us | +-- | root | stage/sql/preparing | 5 | 69.12 us | 13.82 us | +-- | root | stage/sql/optimizing | 5 | 53.11 us | 10.62 us | +-- | root | stage/sql/Sending data | 5 | 44.66 us | 8.93 us | +-- | root | stage/sql/closing tables | 5 | 37.54 us | 7.51 us | +-- | root | stage/sql/System lock | 5 | 34.28 us | 6.86 us | +-- | root | stage/sql/query end | 5 | 24.37 us | 4.87 us | +-- | root | stage/sql/end | 5 | 8.60 us | 1.72 us | +-- | root | stage/sql/Sorting result | 5 | 8.33 us | 1.67 us | +-- | root | stage/sql/executing | 5 | 5.37 us | 1.07 us | +-- | root | stage/sql/cleaning up | 5 | 4.60 us | 919.00 ns | +-- +------+--------------------------------+-------+---------------+-------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW user_summary_by_stages ( + user, + event_name, + total, + total_latency, + avg_latency +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + event_name, + count_star AS total, + sys.format_time(sum_timer_wait) AS total_latency, + sys.format_time(avg_timer_wait) AS avg_latency + FROM performance_schema.events_stages_summary_by_user_by_event_name + WHERE sum_timer_wait != 0 + ORDER BY user, sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/user_summary_by_statement_latency.sql b/scripts/sys_schema/views/p_s/user_summary_by_statement_latency.sql new file mode 100644 index 00000000..2c6e0b50 --- /dev/null +++ b/scripts/sys_schema/views/p_s/user_summary_by_statement_latency.sql @@ -0,0 +1,57 @@ +-- 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: user_summary_by_statement_latency +-- +-- Summarizes overall statement statistics by user. +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from user_summary_by_statement_latency; +-- +------+-------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ +-- | user | total | total_latency | max_latency | lock_latency | rows_sent | rows_examined | rows_affected | full_scans | +-- +------+-------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ +-- | root | 3381 | 00:02:09.13 | 1.48 s | 1.07 s | 1151 | 93947 | 150 | 91 | +-- +------+-------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW user_summary_by_statement_latency ( + user, + total, + total_latency, + max_latency, + lock_latency, + rows_sent, + rows_examined, + rows_affected, + full_scans +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + SUM(count_star) AS total, + sys.format_time(SUM(sum_timer_wait)) AS total_latency, + sys.format_time(SUM(max_timer_wait)) AS max_latency, + sys.format_time(SUM(sum_lock_time)) AS lock_latency, + SUM(sum_rows_sent) AS rows_sent, + SUM(sum_rows_examined) AS rows_examined, + SUM(sum_rows_affected) AS rows_affected, + SUM(sum_no_index_used) + SUM(sum_no_good_index_used) AS full_scans + FROM performance_schema.events_statements_summary_by_user_by_event_name + GROUP BY IF(user IS NULL, 'background', user) + ORDER BY SUM(sum_timer_wait) DESC; diff --git a/scripts/sys_schema/views/p_s/user_summary_by_statement_type.sql b/scripts/sys_schema/views/p_s/user_summary_by_statement_type.sql new file mode 100644 index 00000000..f9ddc2bb --- /dev/null +++ b/scripts/sys_schema/views/p_s/user_summary_by_statement_type.sql @@ -0,0 +1,64 @@ +-- 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: user_summary_by_statement_type +-- +-- Summarizes the types of statements executed by each user. +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from user_summary_by_statement_type; +-- +------+----------------------+--------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ +-- | user | statement | total | total_latency | max_latency | lock_latency | rows_sent | rows_examined | rows_affected | full_scans | +-- +------+----------------------+--------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ +-- | root | create_view | 2063 | 00:05:04.20 | 463.58 ms | 1.42 s | 0 | 0 | 0 | 0 | +-- | root | select | 174 | 40.87 s | 28.83 s | 858.13 ms | 5212 | 157022 | 0 | 82 | +-- | root | stmt | 6645 | 15.31 s | 491.78 ms | 0 ps | 0 | 0 | 7951 | 0 | +-- | root | call_procedure | 17 | 4.78 s | 1.02 s | 37.94 ms | 0 | 0 | 19 | 0 | +-- | root | create_table | 19 | 3.04 s | 431.71 ms | 0 ps | 0 | 0 | 0 | 0 | +-- ... +-- +------+----------------------+--------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW user_summary_by_statement_type ( + user, + statement, + total, + total_latency, + max_latency, + lock_latency, + rows_sent, + rows_examined, + rows_affected, + full_scans +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + SUBSTRING_INDEX(event_name, '/', -1) AS statement, + count_star AS total, + sys.format_time(sum_timer_wait) AS total_latency, + sys.format_time(max_timer_wait) AS max_latency, + sys.format_time(sum_lock_time) AS lock_latency, + sum_rows_sent AS rows_sent, + sum_rows_examined AS rows_examined, + sum_rows_affected AS rows_affected, + sum_no_index_used + sum_no_good_index_used AS full_scans + FROM performance_schema.events_statements_summary_by_user_by_event_name + WHERE sum_timer_wait != 0 + ORDER BY user, sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/wait_classes_global_by_avg_latency.sql b/scripts/sys_schema/views/p_s/wait_classes_global_by_avg_latency.sql new file mode 100644 index 00000000..faee5823 --- /dev/null +++ b/scripts/sys_schema/views/p_s/wait_classes_global_by_avg_latency.sql @@ -0,0 +1,56 @@ +-- 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: wait_classes_global_by_avg_latency +-- +-- Lists the top wait classes by average latency, ignoring idle (this may be very large). +-- +-- mysql> select * from wait_classes_global_by_avg_latency where event_class != 'idle'; +-- +-------------------+--------+---------------+-------------+-------------+-------------+ +-- | event_class | total | total_latency | min_latency | avg_latency | max_latency | +-- +-------------------+--------+---------------+-------------+-------------+-------------+ +-- | wait/io/file | 543123 | 44.60 s | 19.44 ns | 82.11 us | 4.21 s | +-- | wait/io/table | 22002 | 766.60 ms | 148.72 ns | 34.84 us | 44.97 ms | +-- | wait/io/socket | 79613 | 967.17 ms | 0 ps | 12.15 us | 27.10 ms | +-- | wait/lock/table | 35409 | 18.68 ms | 65.45 ns | 527.51 ns | 969.88 us | +-- | wait/synch/rwlock | 37935 | 4.61 ms | 21.38 ns | 121.61 ns | 34.65 us | +-- | wait/synch/mutex | 390622 | 18.60 ms | 19.44 ns | 47.61 ns | 10.32 us | +-- +-------------------+--------+---------------+-------------+-------------+-------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW wait_classes_global_by_avg_latency ( + event_class, + total, + total_latency, + min_latency, + avg_latency, + max_latency +) AS +SELECT SUBSTRING_INDEX(event_name,'/', 3) AS event_class, + SUM(COUNT_STAR) AS total, + sys.format_time(CAST(SUM(sum_timer_wait) AS UNSIGNED)) AS total_latency, + sys.format_time(MIN(min_timer_wait)) AS min_latency, + sys.format_time(IFNULL(SUM(sum_timer_wait) / NULLIF(SUM(COUNT_STAR), 0), 0)) AS avg_latency, + sys.format_time(CAST(MAX(max_timer_wait) AS UNSIGNED)) AS max_latency + FROM performance_schema.events_waits_summary_global_by_event_name + WHERE sum_timer_wait > 0 + AND event_name != 'idle' + GROUP BY event_class + ORDER BY IFNULL(SUM(sum_timer_wait) / NULLIF(SUM(COUNT_STAR), 0), 0) DESC; diff --git a/scripts/sys_schema/views/p_s/wait_classes_global_by_latency.sql b/scripts/sys_schema/views/p_s/wait_classes_global_by_latency.sql new file mode 100644 index 00000000..5675c3f5 --- /dev/null +++ b/scripts/sys_schema/views/p_s/wait_classes_global_by_latency.sql @@ -0,0 +1,56 @@ +-- 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: wait_classes_global_by_latency +-- +-- Lists the top wait classes by total latency, ignoring idle (this may be very large). +-- +-- mysql> select * from wait_classes_global_by_latency; +-- +-------------------+--------+---------------+-------------+-------------+-------------+ +-- | event_class | total | total_latency | min_latency | avg_latency | max_latency | +-- +-------------------+--------+---------------+-------------+-------------+-------------+ +-- | wait/io/file | 550470 | 46.01 s | 19.44 ns | 83.58 us | 4.21 s | +-- | wait/io/socket | 228833 | 2.71 s | 0 ps | 11.86 us | 29.93 ms | +-- | wait/io/table | 64063 | 1.89 s | 99.79 ns | 29.43 us | 68.07 ms | +-- | wait/lock/table | 76029 | 47.19 ms | 65.45 ns | 620.74 ns | 969.88 us | +-- | wait/synch/mutex | 635925 | 34.93 ms | 19.44 ns | 54.93 ns | 107.70 us | +-- | wait/synch/rwlock | 61287 | 7.62 ms | 21.38 ns | 124.37 ns | 34.65 us | +-- +-------------------+--------+---------------+-------------+-------------+-------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW wait_classes_global_by_latency ( + event_class, + total, + total_latency, + min_latency, + avg_latency, + max_latency +) AS +SELECT SUBSTRING_INDEX(event_name,'/', 3) AS event_class, + SUM(COUNT_STAR) AS total, + sys.format_time(SUM(sum_timer_wait)) AS total_latency, + sys.format_time(MIN(min_timer_wait)) min_latency, + sys.format_time(IFNULL(SUM(sum_timer_wait) / NULLIF(SUM(COUNT_STAR), 0), 0)) AS avg_latency, + sys.format_time(MAX(max_timer_wait)) AS max_latency + FROM performance_schema.events_waits_summary_global_by_event_name + WHERE sum_timer_wait > 0 + AND event_name != 'idle' + GROUP BY SUBSTRING_INDEX(event_name,'/', 3) + ORDER BY SUM(sum_timer_wait) DESC; diff --git a/scripts/sys_schema/views/p_s/waits_by_host_by_latency.sql b/scripts/sys_schema/views/p_s/waits_by_host_by_latency.sql new file mode 100644 index 00000000..5587fee2 --- /dev/null +++ b/scripts/sys_schema/views/p_s/waits_by_host_by_latency.sql @@ -0,0 +1,54 @@ +-- 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: waits_by_host_by_latency +-- +-- Lists the top wait events per host by their total latency, ignoring idle (this may be very large). +-- +-- mysql> select * from sys.waits_by_host_by_latency where host != 'background' limit 5; +-- +-----------+------------------------------+-------+---------------+-------------+-------------+ +-- | host | event | total | total_latency | avg_latency | max_latency | +-- +-----------+------------------------------+-------+---------------+-------------+-------------+ +-- | localhost | wait/io/file/sql/file_parser | 1386 | 14.50 s | 10.46 ms | 357.36 ms | +-- | localhost | wait/io/file/sql/FRM | 162 | 356.08 ms | 2.20 ms | 75.33 ms | +-- | localhost | wait/io/file/myisam/kfile | 410 | 322.29 ms | 786.08 us | 65.98 ms | +-- | localhost | wait/io/file/myisam/dfile | 1327 | 307.44 ms | 231.68 us | 37.16 ms | +-- | localhost | wait/io/file/sql/dbopt | 89 | 180.34 ms | 2.03 ms | 63.41 ms | +-- +-----------+------------------------------+-------+---------------+-------------+-------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW waits_by_host_by_latency ( + host, + event, + total, + total_latency, + avg_latency, + max_latency +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + event_name AS event, + count_star AS total, + sys.format_time(sum_timer_wait) AS total_latency, + sys.format_time(avg_timer_wait) AS avg_latency, + sys.format_time(max_timer_wait) AS max_latency + FROM performance_schema.events_waits_summary_by_host_by_event_name + WHERE event_name != 'idle' + AND sum_timer_wait > 0 + ORDER BY host, sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/waits_by_user_by_latency.sql b/scripts/sys_schema/views/p_s/waits_by_user_by_latency.sql new file mode 100644 index 00000000..5a6a618e --- /dev/null +++ b/scripts/sys_schema/views/p_s/waits_by_user_by_latency.sql @@ -0,0 +1,65 @@ +-- 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: waits_by_user_by_latency +-- +-- Lists the top wait events per user by their total latency, ignoring idle (this may be very large). +-- +-- mysql> select * from waits_by_user_by_latency; +-- +------+-----------------------------------------------------+--------+---------------+-------------+-------------+ +-- | user | event | total | total_latency | avg_latency | max_latency | +-- +------+-----------------------------------------------------+--------+---------------+-------------+-------------+ +-- | root | wait/io/file/sql/file_parser | 13743 | 00:01:00.46 | 4.40 ms | 231.88 ms | +-- | root | wait/io/file/innodb/innodb_data_file | 4699 | 3.02 s | 643.38 us | 46.93 ms | +-- | root | wait/io/file/sql/FRM | 11462 | 2.60 s | 226.83 us | 61.72 ms | +-- | root | wait/io/file/myisam/dfile | 26776 | 746.70 ms | 27.89 us | 308.79 ms | +-- | root | wait/io/file/myisam/kfile | 7126 | 462.66 ms | 64.93 us | 88.76 ms | +-- | root | wait/io/file/sql/dbopt | 179 | 137.58 ms | 768.59 us | 15.46 ms | +-- | root | wait/io/file/csv/metadata | 8 | 86.60 ms | 10.82 ms | 50.32 ms | +-- | root | wait/synch/mutex/mysys/IO_CACHE::append_buffer_lock | 798080 | 66.46 ms | 82.94 ns | 161.03 us | +-- | root | wait/io/file/sql/binlog | 19 | 49.11 ms | 2.58 ms | 9.40 ms | +-- | root | wait/io/file/sql/misc | 26 | 22.38 ms | 860.80 us | 15.30 ms | +-- | root | wait/io/file/csv/data | 4 | 297.46 us | 74.37 us | 111.93 us | +-- | root | wait/synch/rwlock/sql/MDL_lock::rwlock | 944 | 287.86 us | 304.62 ns | 874.64 ns | +-- | root | wait/io/file/archive/data | 4 | 82.71 us | 20.68 us | 40.74 us | +-- | root | wait/synch/mutex/myisam/MYISAM_SHARE::intern_lock | 60 | 12.21 us | 203.20 ns | 512.72 ns | +-- | root | wait/synch/mutex/innodb/trx_mutex | 81 | 5.93 us | 73.14 ns | 252.59 ns | +-- +------+-----------------------------------------------------+--------+---------------+-------------+-------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW waits_by_user_by_latency ( + user, + event, + total, + total_latency, + avg_latency, + max_latency +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + event_name AS event, + count_star AS total, + sys.format_time(sum_timer_wait) AS total_latency, + sys.format_time(avg_timer_wait) AS avg_latency, + sys.format_time(max_timer_wait) AS max_latency + FROM performance_schema.events_waits_summary_by_user_by_event_name + WHERE event_name != 'idle' + AND user IS NOT NULL + AND sum_timer_wait > 0 + ORDER BY user, sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/waits_global_by_latency.sql b/scripts/sys_schema/views/p_s/waits_global_by_latency.sql new file mode 100644 index 00000000..a41be3b1 --- /dev/null +++ b/scripts/sys_schema/views/p_s/waits_global_by_latency.sql @@ -0,0 +1,52 @@ +-- 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: waits_global_by_latency +-- +-- Lists the top wait events by their total latency, ignoring idle (this may be very large). +-- +-- mysql> select * from waits_global_by_latency limit 5; +-- +--------------------------------------+------------+---------------+-------------+-------------+ +-- | event | total | total_latency | avg_latency | max_latency | +-- +--------------------------------------+------------+---------------+-------------+-------------+ +-- | wait/io/file/myisam/dfile | 3623719744 | 00:47:49.09 | 791.70 ns | 312.96 ms | +-- | wait/io/table/sql/handler | 69114944 | 00:44:30.74 | 38.64 us | 879.49 ms | +-- | wait/io/file/innodb/innodb_log_file | 28100261 | 00:37:42.12 | 80.50 us | 476.00 ms | +-- | wait/io/socket/sql/client_connection | 200704863 | 00:18:37.81 | 5.57 us | 1.27 s | +-- | wait/io/file/innodb/innodb_data_file | 2829403 | 00:08:12.89 | 174.20 us | 455.22 ms | +-- +--------------------------------------+------------+---------------+-------------+-------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW waits_global_by_latency ( + events, + total, + total_latency, + avg_latency, + max_latency +) AS +SELECT event_name AS event, + count_star AS total, + sys.format_time(sum_timer_wait) AS total_latency, + sys.format_time(avg_timer_wait) AS avg_latency, + sys.format_time(max_timer_wait) AS max_latency + FROM performance_schema.events_waits_summary_global_by_event_name + WHERE event_name != 'idle' + AND sum_timer_wait > 0 + ORDER BY sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/x_host_summary.sql b/scripts/sys_schema/views/p_s/x_host_summary.sql new file mode 100644 index 00000000..87d415b0 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_host_summary.sql @@ -0,0 +1,60 @@ +-- 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: x$host_summary +-- +-- Summarizes statement activity, file IO and connections by host. +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$host_summary; +-- +------+------------+-------------------+-----------------------+-------------+----------+-----------------+---------------------+-------------------+--------------+ +-- | host | statements | statement_latency | statement_avg_latency | table_scans | file_ios | file_io_latency | current_connections | total_connections | unique_users | +-- +------+------------+-------------------+-----------------------+-------------+----------+-----------------+---------------------+-------------------+--------------+ +-- | hal | 2925 | 239577283481000 | 81906763583.2479 | 83 | 54709 | 55605611965150 | 1 | 1 | 1 | +-- +------+------------+-------------------+-----------------------+-------------+----------+-----------------+---------------------+-------------------+--------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$host_summary ( + host, + statements, + statement_latency, + statement_avg_latency, + table_scans, + file_ios, + file_io_latency, + current_connections, + total_connections, + unique_users +) AS +SELECT IF(accounts.host IS NULL, 'background', accounts.host) AS host, + SUM(stmt.total) AS statements, + SUM(stmt.total_latency) AS statement_latency, + SUM(stmt.total_latency) / SUM(stmt.total) AS statement_avg_latency, + SUM(stmt.full_scans) AS table_scans, + SUM(io.ios) AS file_ios, + SUM(io.io_latency) AS file_io_latency, + SUM(accounts.current_connections) AS current_connections, + SUM(accounts.total_connections) AS total_connections, + COUNT(DISTINCT accounts.user) AS unique_users + FROM performance_schema.accounts + LEFT JOIN sys.x$host_summary_by_statement_latency AS stmt ON accounts.host = stmt.host + LEFT JOIN sys.x$host_summary_by_file_io AS io ON accounts.host = io.host + GROUP BY IF(accounts.host IS NULL, 'background', accounts.host); diff --git a/scripts/sys_schema/views/p_s/x_host_summary_57.sql b/scripts/sys_schema/views/p_s/x_host_summary_57.sql new file mode 100644 index 00000000..5a741ade --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_host_summary_57.sql @@ -0,0 +1,66 @@ +-- 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: x$host_summary +-- +-- Summarizes statement activity and connections by host +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$host_summary; +-- +------+------------+-----------------+------------------+---------------------+-------------------+--------------+----------------+------------------------+ +-- | host | statements | total_latency | avg_latency | current_connections | total_connections | unique_users | current_memory | total_memory_allocated | +-- +------+------------+-----------------+------------------+---------------------+-------------------+--------------+----------------+------------------------+ +-- | hal1 | 5685 | 107175100271000 | 18852260381.8821 | 1 | 1 | 1 | 1459022 | 572855680 | +-- | hal2 | 225 | 14489223428000 | 64396548568.8889 | 1 | 1 | 1 | 724578 | 84958286 | +-- +------+------------+-----------------+------------------+---------------------+-------------------+--------------+----------------+------------------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$host_summary ( + host, + statements, + statement_latency, + statement_avg_latency, + table_scans, + file_ios, + file_io_latency, + current_connections, + total_connections, + unique_users, + current_memory, + total_memory_allocated +) AS +SELECT IF(accounts.host IS NULL, 'background', accounts.host) AS host, + SUM(stmt.total) AS statements, + SUM(stmt.total_latency) AS statement_latency, + SUM(stmt.total_latency) / SUM(stmt.total) AS statement_avg_latency, + SUM(stmt.full_scans) AS table_scans, + SUM(io.ios) AS file_ios, + SUM(io.io_latency) AS file_io_latency, + SUM(accounts.current_connections) AS current_connections, + SUM(accounts.total_connections) AS total_connections, + COUNT(DISTINCT accounts.user) AS unique_users, + SUM(mem.current_allocated) AS current_memory, + SUM(mem.total_allocated) AS total_memory_allocated + FROM performance_schema.accounts + JOIN sys.x$host_summary_by_statement_latency AS stmt ON accounts.host = stmt.host + JOIN sys.x$host_summary_by_file_io AS io ON accounts.host = io.host + JOIN sys.x$memory_by_host_by_current_bytes mem ON accounts.host = mem.host + GROUP BY IF(accounts.host IS NULL, 'background', accounts.host); diff --git a/scripts/sys_schema/views/p_s/x_host_summary_by_file_io.sql b/scripts/sys_schema/views/p_s/x_host_summary_by_file_io.sql new file mode 100644 index 00000000..6e1d727a --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_host_summary_by_file_io.sql @@ -0,0 +1,47 @@ +-- 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: x$host_summary_by_file_io +-- +-- Summarizes file IO totals per host. +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$host_summary_by_file_io; +-- +------------+-------+----------------+ +-- | host | ios | io_latency | +-- +------------+-------+----------------+ +-- | hal1 | 26457 | 21579585586390 | +-- | hal2 | 1189 | 394212617370 | +-- +------------+-------+----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$host_summary_by_file_io ( + host, + ios, + io_latency +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + SUM(count_star) AS ios, + SUM(sum_timer_wait) AS io_latency + FROM performance_schema.events_waits_summary_by_host_by_event_name + WHERE event_name LIKE 'wait/io/file/%' + GROUP BY IF(host IS NULL, 'background', host) + ORDER BY SUM(sum_timer_wait) DESC; diff --git a/scripts/sys_schema/views/p_s/x_host_summary_by_file_io_type.sql b/scripts/sys_schema/views/p_s/x_host_summary_by_file_io_type.sql new file mode 100644 index 00000000..e272732d --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_host_summary_by_file_io_type.sql @@ -0,0 +1,66 @@ +-- 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: x$host_summary_by_file_io_type +-- +-- Summarizes file IO by event type per host. +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$host_summary_by_file_io_type; +-- +------------+--------------------------------------+-------+---------------+--------------+ +-- | host | event_name | total | total_latency | max_latency | +-- +------------+--------------------------------------+-------+---------------+--------------+ +-- | hal1 | wait/io/file/sql/FRM | 871 | 168148450470 | 18482624810 | +-- | hal1 | wait/io/file/innodb/innodb_data_file | 173 | 129564287450 | 34087423890 | +-- | hal1 | wait/io/file/innodb/innodb_log_file | 20 | 77525706960 | 60657475320 | +-- | hal1 | wait/io/file/myisam/dfile | 40 | 6544493800 | 4580546230 | +-- | hal1 | wait/io/file/mysys/charset | 3 | 4793558770 | 4713476430 | +-- | hal1 | wait/io/file/myisam/kfile | 67 | 4384332810 | 300035450 | +-- | hal1 | wait/io/file/sql/ERRMSG | 5 | 2717434850 | 1687316280 | +-- | hal1 | wait/io/file/sql/pid | 3 | 266301490 | 185468920 | +-- | hal1 | wait/io/file/sql/casetest | 5 | 246814360 | 150193030 | +-- | hal1 | wait/io/file/sql/global_ddl_log | 2 | 21236410 | 18593640 | +-- | hal2 | wait/io/file/sql/file_parser | 1422 | 4801104756760 | 135138518970 | +-- | hal2 | wait/io/file/sql/FRM | 865 | 85818594810 | 9812303410 | +-- | hal2 | wait/io/file/myisam/kfile | 1073 | 37143664870 | 15793838190 | +-- | hal2 | wait/io/file/myisam/dfile | 2991 | 25528215700 | 5252232050 | +-- | hal2 | wait/io/file/sql/dbopt | 20 | 1067339780 | 153073310 | +-- | hal2 | wait/io/file/sql/misc | 4 | 59713030 | 33752810 | +-- | hal2 | wait/io/file/archive/data | 1 | 13907530 | 13907530 | +-- +------------+--------------------------------------+-------+---------------+--------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$host_summary_by_file_io_type ( + host, + event_name, + total, + total_latency, + max_latency +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + event_name, + count_star AS total, + sum_timer_wait AS total_latency, + max_timer_wait AS max_latency + FROM performance_schema.events_waits_summary_by_host_by_event_name + WHERE event_name LIKE 'wait/io/file%' + AND count_star > 0 + ORDER BY IF(host IS NULL, 'background', host), sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/x_host_summary_by_stages.sql b/scripts/sys_schema/views/p_s/x_host_summary_by_stages.sql new file mode 100644 index 00000000..801d338e --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_host_summary_by_stages.sql @@ -0,0 +1,64 @@ +-- 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: x$host_summary_by_stages +-- +-- Summarizes stages by host, ordered by host and total latency per stage. +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$host_summary_by_stages; +-- +------+--------------------------------+-------+---------------+-------------+ +-- | host | event_name | total | total_latency | avg_latency | +-- +------+--------------------------------+-------+---------------+-------------+ +-- | hal | stage/sql/Opening tables | 1114 | 71919037000 | 64559000 | +-- | hal | stage/sql/Creating sort index | 5 | 2245762000 | 449152000 | +-- | hal | stage/sql/init | 13 | 428798000 | 32984000 | +-- | hal | stage/sql/checking permissions | 13 | 363231000 | 27940000 | +-- | hal | stage/sql/freeing items | 7 | 137728000 | 19675000 | +-- | hal | stage/sql/statistics | 6 | 93955000 | 15659000 | +-- | hal | stage/sql/preparing | 6 | 82571000 | 13761000 | +-- | hal | stage/sql/optimizing | 6 | 63338000 | 10556000 | +-- | hal | stage/sql/Sending data | 6 | 53400000 | 8900000 | +-- | hal | stage/sql/closing tables | 7 | 46922000 | 6703000 | +-- | hal | stage/sql/System lock | 6 | 40175000 | 6695000 | +-- | hal | stage/sql/query end | 7 | 31723000 | 4531000 | +-- | hal | stage/sql/Sorting result | 6 | 9855000 | 1642000 | +-- | hal | stage/sql/end | 6 | 9556000 | 1592000 | +-- | hal | stage/sql/cleaning up | 7 | 7312000 | 1044000 | +-- | hal | stage/sql/executing | 6 | 6487000 | 1081000 | +-- +------+--------------------------------+-------+---------------+-------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$host_summary_by_stages ( + host, + event_name, + total, + total_latency, + avg_latency +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + event_name, + count_star AS total, + sum_timer_wait AS total_latency, + avg_timer_wait AS avg_latency + FROM performance_schema.events_stages_summary_by_host_by_event_name + WHERE sum_timer_wait != 0 + ORDER BY IF(host IS NULL, 'background', host), sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/x_host_summary_by_statement_latency.sql b/scripts/sys_schema/views/p_s/x_host_summary_by_statement_latency.sql new file mode 100644 index 00000000..30a6e390 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_host_summary_by_statement_latency.sql @@ -0,0 +1,57 @@ +-- 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: x$host_summary_by_statement_latency +-- +-- Summarizes overall statement statistics by host. +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$host_summary_by_statement_latency; +-- +------+-------+-----------------+---------------+---------------+-----------+---------------+---------------+------------+ +-- | host | total | total_latency | max_latency | lock_latency | rows_sent | rows_examined | rows_affected | full_scans | +-- +------+-------+-----------------+---------------+---------------+-----------+---------------+---------------+------------+ +-- | hal | 3382 | 129134039432000 | 1483246743000 | 1069831000000 | 1152 | 94286 | 150 | 92 | +-- +------+-------+-----------------+---------------+---------------+-----------+---------------+---------------+------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$host_summary_by_statement_latency ( + host, + total, + total_latency, + max_latency, + lock_latency, + rows_sent, + rows_examined, + rows_affected, + full_scans +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + SUM(count_star) AS total, + SUM(sum_timer_wait) AS total_latency, + MAX(max_timer_wait) AS max_latency, + SUM(sum_lock_time) AS lock_latency, + SUM(sum_rows_sent) AS rows_sent, + SUM(sum_rows_examined) AS rows_examined, + SUM(sum_rows_affected) AS rows_affected, + SUM(sum_no_index_used) + SUM(sum_no_good_index_used) AS full_scans + FROM performance_schema.events_statements_summary_by_host_by_event_name + GROUP BY IF(host IS NULL, 'background', host) + ORDER BY SUM(sum_timer_wait) DESC; diff --git a/scripts/sys_schema/views/p_s/x_host_summary_by_statement_type.sql b/scripts/sys_schema/views/p_s/x_host_summary_by_statement_type.sql new file mode 100644 index 00000000..72b75b9c --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_host_summary_by_statement_type.sql @@ -0,0 +1,64 @@ +-- 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: x$host_summary_by_statement_type +-- +-- Summarizes the types of statements executed by each host. +-- +-- When the host found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$host_summary_by_statement_type; +-- +------+----------------------+--------+-----------------+----------------+----------------+-----------+---------------+---------------+------------+ +-- | host | statement | total | total_latency | max_latency | lock_latency | rows_sent | rows_examined | rows_affected | full_scans | +-- +------+----------------------+--------+-----------------+----------------+----------------+-----------+---------------+---------------+------------+ +-- | hal | create_view | 2110 | 312717366332000 | 463578029000 | 1432355000000 | 0 | 0 | 0 | 0 | +-- | hal | select | 177 | 41115690428000 | 28827579292000 | 858709000000 | 5254 | 157437 | 0 | 83 | +-- | hal | stmt | 6645 | 15305389969000 | 491780297000 | 0 | 0 | 0 | 7951 | 0 | +-- | hal | call_procedure | 17 | 4783806053000 | 1016083397000 | 37936000000 | 0 | 0 | 19 | 0 | +-- | hal | create_table | 19 | 3035120946000 | 431706815000 | 0 | 0 | 0 | 0 | 0 | +-- ... +-- +------+----------------------+--------+-----------------+----------------+----------------+-----------+---------------+---------------+------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$host_summary_by_statement_type ( + host, + statement, + total, + total_latency, + max_latency, + lock_latency, + rows_sent, + rows_examined, + rows_affected, + full_scans +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + SUBSTRING_INDEX(event_name, '/', -1) AS statement, + count_star AS total, + sum_timer_wait AS total_latency, + max_timer_wait AS max_latency, + sum_lock_time AS lock_latency, + sum_rows_sent AS rows_sent, + sum_rows_examined AS rows_examined, + sum_rows_affected AS rows_affected, + sum_no_index_used + sum_no_good_index_used AS full_scans + FROM performance_schema.events_statements_summary_by_host_by_event_name + WHERE sum_timer_wait != 0 + ORDER BY IF(host IS NULL, 'background', host), sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/x_io_by_thread_by_latency.sql b/scripts/sys_schema/views/p_s/x_io_by_thread_by_latency.sql new file mode 100644 index 00000000..5e02f528 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_io_by_thread_by_latency.sql @@ -0,0 +1,70 @@ +-- 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: x$io_by_thread_by_latency +-- +-- Show the top IO consumers by thread, ordered by total latency +-- +-- mysql> select * from x$io_by_thread_by_latency; +-- +---------------------+-------+----------------+-------------+-----------------+--------------+-----------+----------------+ +-- | user | total | total_latency | min_latency | avg_latency | max_latency | thread_id | processlist_id | +-- +---------------------+-------+----------------+-------------+-----------------+--------------+-----------+----------------+ +-- | root@localhost | 11587 | 18007539905680 | 429780 | 1120831681.6667 | 181065665560 | 25 | 6 | +-- | main | 1358 | 1309001741320 | 475020 | 2269581997.8000 | 350700491310 | 1 | NULL | +-- | page_cleaner_thread | 654 | 147435455960 | 588120 | 225436198.0000 | 46412043990 | 18 | NULL | +-- | io_write_thread | 131 | 107754483070 | 8603140 | 822553303.0000 | 27691592500 | 8 | NULL | +-- | io_write_thread | 46 | 47074926860 | 10642710 | 1023367631.0000 | 16899745070 | 9 | NULL | +-- | io_write_thread | 71 | 46988801210 | 9108320 | 661814075.0000 | 17042760020 | 11 | NULL | +-- | io_log_thread | 20 | 21007710490 | 14250600 | 1050385336.0000 | 7081255090 | 3 | NULL | +-- | srv_master_thread | 13 | 17601511720 | 8486270 | 1353962324.0000 | 9990100380 | 16 | NULL | +-- | srv_purge_thread | 4 | 1809792270 | 34307000 | 452447879.0000 | 1018887740 | 17 | NULL | +-- | io_write_thread | 19 | 951385890 | 9745450 | 50072763.0000 | 297468080 | 10 | NULL | +-- | signal_handler | 3 | 218026640 | 21639800 | 72675421.0000 | 154841440 | 19 | NULL | +-- +---------------------+-------+----------------+-------------+-----------------+--------------+-----------+----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$io_by_thread_by_latency ( + user, + total, + total_latency, + min_latency, + avg_latency, + max_latency, + thread_id, + processlist_id +) +AS +SELECT IF(processlist_id IS NULL, + SUBSTRING_INDEX(name, '/', -1), + CONCAT(processlist_user, '@', processlist_host) + ) user, + SUM(count_star) total, + SUM(sum_timer_wait) total_latency, + MIN(min_timer_wait) min_latency, + AVG(avg_timer_wait) avg_latency, + MAX(max_timer_wait) max_latency, + thread_id, + processlist_id + FROM performance_schema.events_waits_summary_by_thread_by_event_name + LEFT JOIN performance_schema.threads USING (thread_id) + WHERE event_name LIKE 'wait/io/file/%' + AND sum_timer_wait > 0 + GROUP BY thread_id, processlist_id, user + ORDER BY SUM(sum_timer_wait) DESC; diff --git a/scripts/sys_schema/views/p_s/x_io_global_by_file_by_bytes.sql b/scripts/sys_schema/views/p_s/x_io_global_by_file_by_bytes.sql new file mode 100644 index 00000000..d508deb1 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_io_global_by_file_by_bytes.sql @@ -0,0 +1,58 @@ +-- 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: x$io_global_by_file_by_bytes +-- +-- Shows the top global IO consumers by bytes usage by file. +-- +-- mysql> SELECT * FROM x$io_global_by_file_by_bytes LIMIT 5; +-- +------------------------------------------------------+------------+------------+------------+-------------+---------------+------------+---------+-----------+ +-- | file | count_read | total_read | avg_read | count_write | total_written | avg_write | total | write_pct | +-- +------------------------------------------------------+------------+------------+------------+-------------+---------------+------------+---------+-----------+ +-- | /Users/mark/sandboxes/msb_5_5_33/data/ibdata1 | 147 | 4472832 | 30427.4286 | 3 | 49152 | 16384.0000 | 4521984 | 1.09 | +-- | /Users/mark/sandboxes/msb_5_5_33/data/mysql/proc.MYD | 347 | 87397 | 251.8646 | 111 | 19536 | 176.0000 | 106933 | 18.27 | +-- | /Users/mark/sandboxes/msb_5_5_33/data/ib_logfile0 | 6 | 69632 | 11605.3333 | 8 | 4096 | 512.0000 | 73728 | 5.56 | +-- | /opt/mysql/5.5.33/share/english/errmsg.sys | 3 | 44724 | 14908.0000 | 0 | 0 | 0.0000 | 44724 | 0.00 | +-- | /opt/mysql/5.5.33/share/charsets/Index.xml | 1 | 18317 | 18317.0000 | 0 | 0 | 0.0000 | 18317 | 0.00 | +-- +------------------------------------------------------+------------+------------+------------+-------------+---------------+------------+---------+-----------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$io_global_by_file_by_bytes ( + file, + count_read, + total_read, + avg_read, + count_write, + total_written, + avg_write, + total, + write_pct +) AS +SELECT file_name AS file, + count_read, + sum_number_of_bytes_read AS total_read, + IFNULL(sum_number_of_bytes_read / NULLIF(count_read, 0), 0) AS avg_read, + count_write, + sum_number_of_bytes_write AS total_written, + IFNULL(sum_number_of_bytes_write / NULLIF(count_write, 0), 0.00) AS avg_write, + sum_number_of_bytes_read + sum_number_of_bytes_write AS total, + IFNULL(ROUND(100-((sum_number_of_bytes_read/ NULLIF((sum_number_of_bytes_read+sum_number_of_bytes_write), 0))*100), 2), 0.00) AS write_pct + FROM performance_schema.file_summary_by_instance + ORDER BY sum_number_of_bytes_read + sum_number_of_bytes_write DESC; diff --git a/scripts/sys_schema/views/p_s/x_io_global_by_file_by_latency.sql b/scripts/sys_schema/views/p_s/x_io_global_by_file_by_latency.sql new file mode 100644 index 00000000..b1229ff4 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_io_global_by_file_by_latency.sql @@ -0,0 +1,58 @@ +-- 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: x$io_global_by_file_by_latency +-- +-- Shows the top global IO consumers by latency by file. +-- +-- mysql> select * from x$io_global_by_file_by_latency limit 5; +-- +--------------------------------------------------------------------------------------+-------+---------------+------------+--------------+-------------+---------------+------------+--------------+ +-- | file | total | total_latency | count_read | read_latency | count_write | write_latency | count_misc | misc_latency | +-- +--------------------------------------------------------------------------------------+-------+---------------+------------+--------------+-------------+---------------+------------+--------------+ +-- | /Users/mark/sandboxes/msb_5_7_2/data/sys/wait_classes_global_by_avg_latency_raw.frm~ | 30 | 513959738110 | 0 | 0 | 5 | 132130960 | 25 | 513827607150 | +-- | /Users/mark/sandboxes/msb_5_7_2/data/sys/innodb_buffer_stats_by_schema_raw.frm~ | 30 | 490149888410 | 0 | 0 | 5 | 483887040 | 25 | 489666001370 | +-- | /Users/mark/sandboxes/msb_5_7_2/data/sys/io_by_thread_by_latency_raw.frm~ | 30 | 427724241620 | 0 | 0 | 5 | 131399580 | 25 | 427592842040 | +-- | /Users/mark/sandboxes/msb_5_7_2/data/sys/innodb_buffer_stats_by_schema.frm~ | 30 | 406392559950 | 0 | 0 | 5 | 104082160 | 25 | 406288477790 | +-- | /Users/mark/sandboxes/msb_5_7_2/data/sys/statement_analysis_raw.frm~ | 30 | 395527510430 | 0 | 0 | 5 | 118724840 | 25 | 395408785590 | +-- +--------------------------------------------------------------------------------------+-------+---------------+------------+--------------+-------------+---------------+------------+--------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$io_global_by_file_by_latency ( + file, + total, + total_latency, + count_read, + read_latency, + count_write, + write_latency, + count_misc, + misc_latency +) AS +SELECT file_name AS file, + count_star AS total, + sum_timer_wait AS total_latency, + count_read, + sum_timer_read AS read_latency, + count_write, + sum_timer_write AS write_latency, + count_misc, + sum_timer_misc AS misc_latency + FROM performance_schema.file_summary_by_instance + ORDER BY sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/x_io_global_by_wait_by_bytes.sql b/scripts/sys_schema/views/p_s/x_io_global_by_wait_by_bytes.sql new file mode 100644 index 00000000..1ec6e9ce --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_io_global_by_wait_by_bytes.sql @@ -0,0 +1,74 @@ +-- 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: x$io_global_by_wait_by_bytes +-- +-- Shows the top global IO consumer classes by bytes usage. +-- +-- mysql> select * from x$io_global_by_wait_by_bytes; +-- +-------------------------+-------+---------------+-------------+-------------+--------------+------------+------------+------------+-------------+---------------+-------------+-----------------+ +-- | event_name | total | total_latency | min_latency | avg_latency | max_latency | count_read | total_read | avg_read | count_write | total_written | avg_written | total_requested | +-- +-------------------------+-------+---------------+-------------+-------------+--------------+------------+------------+------------+-------------+---------------+-------------+-----------------+ +-- | innodb/innodb_data_file | 151 | 334405721910 | 8399560 | 2214607429 | 107444600380 | 147 | 4472832 | 30427.4286 | 0 | 0 | 0.0000 | 4472832 | +-- | sql/FRM | 555 | 147752034170 | 674830 | 266219881 | 57705900850 | 270 | 112174 | 415.4593 | 0 | 0 | 0.0000 | 112174 | +-- | innodb/innodb_log_file | 22 | 56776429970 | 2476890 | 2580746816 | 18883021430 | 6 | 69632 | 11605.3333 | 5 | 2560 | 512.0000 | 72192 | +-- | sql/ERRMSG | 5 | 11862056180 | 14883960 | 2372411236 | 11109473700 | 3 | 44724 | 14908.0000 | 0 | 0 | 0.0000 | 44724 | +-- | mysys/charset | 3 | 7256869230 | 19796270 | 2418956410 | 7198498320 | 1 | 18317 | 18317.0000 | 0 | 0 | 0.0000 | 18317 | +-- | myisam/kfile | 135 | 10194698280 | 784160 | 75516283 | 2593514950 | 40 | 9216 | 230.4000 | 33 | 1017 | 30.8182 | 10233 | +-- | myisam/dfile | 68 | 10527909730 | 772850 | 154822201 | 7600014630 | 9 | 6667 | 740.7778 | 0 | 0 | 0.0000 | 6667 | +-- | sql/pid | 3 | 216507330 | 41296580 | 72169110 | 100617530 | 0 | 0 | 0.0000 | 1 | 6 | 6.0000 | 6 | +-- | sql/casetest | 5 | 185261570 | 4105530 | 37052314 | 113488310 | 0 | 0 | 0.0000 | 0 | 0 | 0.0000 | 0 | +-- | sql/global_ddl_log | 2 | 21538010 | 3121560 | 10769005 | 18416450 | 0 | 0 | 0.0000 | 0 | 0 | 0.0000 | 0 | +-- | sql/dbopt | 10 | 1004267680 | 1164930 | 100426768 | 939894930 | 0 | 0 | 0.0000 | 0 | 0 | 0.0000 | 0 | +-- +-------------------------+-------+---------------+-------------+-------------+--------------+------------+------------+------------+-------------+---------------+-------------+-----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$io_global_by_wait_by_bytes ( + event_name, + total, + total_latency, + min_latency, + avg_latency, + max_latency, + count_read, + total_read, + avg_read, + count_write, + total_written, + avg_written, + total_requested +) AS +SELECT SUBSTRING_INDEX(event_name, '/', -2) AS event_name, + count_star AS total, + sum_timer_wait AS total_latency, + min_timer_wait AS min_latency, + avg_timer_wait AS avg_latency, + max_timer_wait AS max_latency, + count_read, + sum_number_of_bytes_read AS total_read, + IFNULL(sum_number_of_bytes_read / NULLIF(count_read, 0), 0) AS avg_read, + count_write, + sum_number_of_bytes_write AS total_written, + IFNULL(sum_number_of_bytes_write / NULLIF(count_write, 0), 0) AS avg_written, + sum_number_of_bytes_write + sum_number_of_bytes_read AS total_requested + FROM performance_schema.file_summary_by_event_name + WHERE event_name LIKE 'wait/io/file/%' + AND count_star > 0 + ORDER BY sum_number_of_bytes_write + sum_number_of_bytes_read DESC; diff --git a/scripts/sys_schema/views/p_s/x_io_global_by_wait_by_latency.sql b/scripts/sys_schema/views/p_s/x_io_global_by_wait_by_latency.sql new file mode 100644 index 00000000..23fb1f81 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_io_global_by_wait_by_latency.sql @@ -0,0 +1,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: x$io_global_by_wait_by_latency +-- +-- Shows the top global IO consumers by latency. +-- +-- mysql> select * from x$io_global_by_wait_by_latency; +-- +-------------------------+-------+----------------+-------------+--------------+--------------+---------------+----------------+------------+------------+------------+-------------+---------------+-------------+ +-- | event_name | total | total_latency | avg_latency | max_latency | read_latency | write_latency | misc_latency | count_read | total_read | avg_read | count_write | total_written | avg_written | +-- +-------------------------+-------+----------------+-------------+--------------+--------------+---------------+----------------+------------+------------+------------+-------------+---------------+-------------+ +-- | sql/file_parser | 5945 | 33615441247050 | 5654405471 | 203652881640 | 22093704230 | 27389668280 | 33565957874540 | 26 | 7008 | 269.5385 | 808 | 2479209 | 3068.3280 | +-- | sql/FRM | 6332 | 1755386796800 | 277224688 | 145624702340 | 519139578620 | 1677016640 | 1234570201540 | 2040 | 865905 | 424.4632 | 439 | 103445 | 235.6378 | +-- | innodb/innodb_data_file | 1344 | 1522989889460 | 1133176798 | 350700491310 | 203817502460 | 450959403830 | 868212983170 | 147 | 2408448 | 16384.0000 | 1001 | 56213504 | 56157.3467 | +-- | innodb/innodb_log_file | 828 | 893475794640 | 1079076921 | 30108124800 | 16315236730 | 705886928240 | 171273629670 | 6 | 69632 | 11605.3333 | 413 | 2294272 | 5555.1380 | +-- | myisam/kfile | 7826 | 246001992860 | 31433883 | 19265276810 | 74419162870 | 23923730090 | 147659099900 | 770 | 141058 | 183.1922 | 4516 | 249602 | 55.2706 | +-- | myisam/dfile | 13431 | 228191713620 | 16989882 | 32500163410 | 89162969350 | 17341973610 | 121686770660 | 5819 | 4873176 | 837.4594 | 1577 | 2853444 | 1809.4128 | +-- | csv/metadata | 8 | 28975194560 | 3621899320 | 20148109020 | 399265620 | 0 | 28575928940 | 2 | 70 | 35.0000 | 0 | 0 | 0.0000 | +-- | mysys/charset | 3 | 24244722970 | 8081574072 | 24151547420 | 24151547420 | 0 | 93175550 | 1 | 17722 | 17722.0000 | 0 | 0 | 0.0000 | +-- | sql/ERRMSG | 5 | 20427386850 | 4085477370 | 19312386730 | 20324183100 | 0 | 103203750 | 3 | 60390 | 20130.0000 | 0 | 0 | 0.0000 | +-- | mysys/cnf | 5 | 11366169230 | 2273233846 | 11283602460 | 11287953040 | 0 | 78216190 | 3 | 56 | 18.6667 | 0 | 0 | 0.0000 | +-- | sql/dbopt | 57 | 4042348570 | 70918224 | 843703380 | 0 | 186430270 | 3855918300 | 0 | 0 | 0.0000 | 7 | 431 | 61.5714 | +-- | csv/data | 4 | 411548280 | 102887070 | 234886080 | 0 | 0 | 411548280 | 0 | 0 | 0.0000 | 0 | 0 | 0.0000 | +-- | sql/misc | 24 | 369128240 | 15380092 | 33771660 | 0 | 0 | 369128240 | 0 | 0 | 0.0000 | 0 | 0 | 0.0000 | +-- | archive/data | 39 | 277856540 | 7124169 | 16180840 | 0 | 0 | 277856540 | 0 | 0 | 0.0000 | 0 | 0 | 0.0000 | +-- | sql/pid | 3 | 218026640 | 72675421 | 154841440 | 0 | 21639800 | 196386840 | 0 | 0 | 0.0000 | 1 | 6 | 6.0000 | +-- | sql/casetest | 5 | 197152150 | 39430430 | 126310080 | 0 | 0 | 197152150 | 0 | 0 | 0.0000 | 0 | 0 | 0.0000 | +-- | sql/global_ddl_log | 2 | 14604980 | 7302490 | 12120550 | 0 | 0 | 14604980 | 0 | 0 | 0.0000 | 0 | 0 | 0.0000 | +-- +-------------------------+-------+----------------+-------------+--------------+--------------+---------------+----------------+------------+------------+------------+-------------+---------------+-------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$io_global_by_wait_by_latency ( + event_name, + total, + total_latency, + avg_latency, + max_latency, + read_latency, + write_latency, + misc_latency, + count_read, + total_read, + avg_read, + count_write, + total_written, + avg_written +) AS +SELECT SUBSTRING_INDEX(event_name, '/', -2) AS event_name, + count_star AS total, + sum_timer_wait AS total_latency, + avg_timer_wait AS avg_latency, + max_timer_wait AS max_latency, + sum_timer_read AS read_latency, + sum_timer_write AS write_latency, + sum_timer_misc AS misc_latency, + count_read, + sum_number_of_bytes_read AS total_read, + IFNULL(sum_number_of_bytes_read / NULLIF(count_read, 0), 0) AS avg_read, + count_write, + sum_number_of_bytes_write AS total_written, + IFNULL(sum_number_of_bytes_write / NULLIF(count_write, 0), 0) AS avg_written + FROM performance_schema.file_summary_by_event_name + WHERE event_name LIKE 'wait/io/file/%' + AND count_star > 0 + ORDER BY sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/x_latest_file_io.sql b/scripts/sys_schema/views/p_s/x_latest_file_io.sql new file mode 100644 index 00000000..7cef7b89 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_latest_file_io.sql @@ -0,0 +1,57 @@ +-- 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: x$latest_file_io +-- +-- Shows the latest file IO, by file / thread. +-- +-- mysql> SELECT * FROM x$latest_file_io LIMIT 5; +-- +------------------+------------------------------------------------------------------------------------+-------------+-----------+-----------+ +-- | thread | file | latency | operation | requested | +-- +------------------+------------------------------------------------------------------------------------+-------------+-----------+-----------+ +-- | root@localhost:6 | /Users/mark/sandboxes/msb_5_7_2/data/ps_helper/user_summary_by_statement_type.frm~ | 26152490 | write | 4210 | +-- | root@localhost:6 | /Users/mark/sandboxes/msb_5_7_2/data/ps_helper/user_summary_by_statement_type.frm~ | 30062722690 | sync | NULL | +-- | root@localhost:6 | /Users/mark/sandboxes/msb_5_7_2/data/ps_helper/user_summary_by_statement_type.frm~ | 34144890 | close | NULL | +-- | root@localhost:6 | /Users/mark/sandboxes/msb_5_7_2/data/ps_helper/check_lost_instrumentation.frm | 113001980 | open | NULL | +-- | root@localhost:6 | /Users/mark/sandboxes/msb_5_7_2/data/ps_helper/check_lost_instrumentation.frm | 9553180 | read | 10 | +-- +------------------+------------------------------------------------------------------------------------+-------------+-----------+-----------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$latest_file_io ( + thread, + file, + latency, + operation, + requested +) AS +SELECT IF(id IS NULL, + CONCAT(SUBSTRING_INDEX(name, '/', -1), ':', thread_id), + CONCAT(user, '@', host, ':', id) + ) thread, + object_name file, + timer_wait AS latency, + operation, + number_of_bytes AS requested + FROM performance_schema.events_waits_history_long + JOIN performance_schema.threads USING (thread_id) + LEFT JOIN information_schema.processlist ON processlist_id = id + WHERE object_name IS NOT NULL + AND event_name LIKE 'wait/io/file/%' + ORDER BY timer_start; diff --git a/scripts/sys_schema/views/p_s/x_memory_by_host_by_current_bytes.sql b/scripts/sys_schema/views/p_s/x_memory_by_host_by_current_bytes.sql new file mode 100644 index 00000000..1fc38197 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_memory_by_host_by_current_bytes.sql @@ -0,0 +1,52 @@ +-- 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: x$memory_by_host_by_current_bytes +-- +-- Summarizes memory use by host +-- +-- When the host found is NULL, it is assumed to be a local "background" thread. +-- +-- mysql> select * from x$memory_by_host_by_current_bytes; +-- +------------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- | host | current_count_used | current_allocated | current_avg_alloc | current_max_alloc | total_allocated | +-- +------------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- | background | 2773 | 11362444 | 4097.5276 | 8390792 | 32184183 | +-- | localhost | 1508 | 813040 | 539.1512 | 180616 | 88168182 | +-- +------------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$memory_by_host_by_current_bytes ( + host, + current_count_used, + current_allocated, + current_avg_alloc, + current_max_alloc, + total_allocated +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + SUM(current_count_used) AS current_count_used, + SUM(current_number_of_bytes_used) AS current_allocated, + IFNULL(SUM(current_number_of_bytes_used) / NULLIF(SUM(current_count_used), 0), 0) AS current_avg_alloc, + MAX(current_number_of_bytes_used) AS current_max_alloc, + SUM(sum_number_of_bytes_alloc) AS total_allocated + FROM performance_schema.memory_summary_by_host_by_event_name + GROUP BY IF(host IS NULL, 'background', host) + ORDER BY SUM(current_number_of_bytes_used) DESC; diff --git a/scripts/sys_schema/views/p_s/x_memory_by_thread_by_current_bytes.sql b/scripts/sys_schema/views/p_s/x_memory_by_thread_by_current_bytes.sql new file mode 100644 index 00000000..3f4098bd --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_memory_by_thread_by_current_bytes.sql @@ -0,0 +1,62 @@ +-- 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: x$memory_by_thread_by_current_bytes +-- +-- Summarizes memory use by user +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from sys.x$memory_by_thread_by_current_bytes limit 5; +-- +-----------+----------------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- | thread_id | user | current_count_used | current_allocated | current_avg_alloc | current_max_alloc | total_allocated | +-- +-----------+----------------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- | 1 | sql/main | 29333 | 174089450 | 5934.9351 | 137494528 | 205523135 | +-- | 55 | root@localhost | 173 | 1074664 | 6211.9306 | 359280 | 72248413 | +-- | 58 | root@localhost | 240 | 377099 | 1571.2458 | 319536 | 169483870 | +-- | 1152 | root@localhost | 30 | 56949 | 1898.3000 | 16391 | 1010024 | +-- | 1154 | root@localhost | 34 | 56369 | 1657.9118 | 16391 | 1958771 | +-- +-----------+----------------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$memory_by_thread_by_current_bytes ( + thread_id, + user, + current_count_used, + current_allocated, + current_avg_alloc, + current_max_alloc, + total_allocated +) AS +SELECT t.thread_id, + IF(t.name = 'thread/sql/one_connection', + CONCAT(t.processlist_user, '@', t.processlist_host), + REPLACE(t.name, 'thread/', '')) user, + SUM(mt.current_count_used) AS current_count_used, + SUM(mt.current_number_of_bytes_used) AS current_allocated, + IFNULL(SUM(mt.current_number_of_bytes_used) / NULLIF(SUM(current_count_used), 0), 0) AS current_avg_alloc, + MAX(mt.current_number_of_bytes_used) AS current_max_alloc, + SUM(mt.sum_number_of_bytes_alloc) AS total_allocated + FROM performance_schema.memory_summary_by_thread_by_event_name AS mt + JOIN performance_schema.threads AS t USING (thread_id) + GROUP BY thread_id, IF(t.name = 'thread/sql/one_connection', + CONCAT(t.processlist_user, '@', t.processlist_host), + REPLACE(t.name, 'thread/', '')) + ORDER BY SUM(mt.current_number_of_bytes_used) DESC; diff --git a/scripts/sys_schema/views/p_s/x_memory_by_user_by_current_bytes.sql b/scripts/sys_schema/views/p_s/x_memory_by_user_by_current_bytes.sql new file mode 100644 index 00000000..794fc568 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_memory_by_user_by_current_bytes.sql @@ -0,0 +1,52 @@ +-- 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: x$memory_by_user_by_current_bytes +-- +-- Summarizes memory use by user +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$memory_by_user_by_current_bytes; +-- +------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- | user | current_count_used | current_allocated | current_avg_alloc | current_max_alloc | total_allocated | +-- +------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- | root | 1399 | 1124553 | 803.8263 | 343008 | 45426133 | +-- | mark | 201 | 507990 | 2527.3134 | 343008 | 5769804 | +-- +------+--------------------+-------------------+-------------------+-------------------+-----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$memory_by_user_by_current_bytes ( + user, + current_count_used, + current_allocated, + current_avg_alloc, + current_max_alloc, + total_allocated +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + SUM(current_count_used) AS current_count_used, + SUM(current_number_of_bytes_used) AS current_allocated, + IFNULL(SUM(current_number_of_bytes_used) / NULLIF(SUM(current_count_used), 0), 0) AS current_avg_alloc, + MAX(current_number_of_bytes_used) AS current_max_alloc, + SUM(sum_number_of_bytes_alloc) AS total_allocated + FROM performance_schema.memory_summary_by_user_by_event_name + GROUP BY IF(user IS NULL, 'background', user) + ORDER BY SUM(current_number_of_bytes_used) DESC; diff --git a/scripts/sys_schema/views/p_s/x_memory_global_by_current_bytes.sql b/scripts/sys_schema/views/p_s/x_memory_global_by_current_bytes.sql new file mode 100644 index 00000000..986c4452 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_memory_global_by_current_bytes.sql @@ -0,0 +1,56 @@ +-- 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: x$memory_global_by_current_bytes +-- +-- Shows the current memory usage within the server globally broken down by allocation type. +-- +-- mysql> select * from x$memory_global_by_current_bytes; +-- +-------------------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+ +-- | event_name | current_count | current_alloc | current_avg_alloc | high_count | high_alloc | high_avg_alloc | +-- +-------------------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+ +-- | memory/performance_schema/internal_buffers | 62 | 308073712 | 4968930.8387 | 62 | 308073712 | 4968930.8387 | +-- | memory/innodb/buf_buf_pool | 1 | 137428992 | 137428992.0000 | 1 | 137428992 | 137428992.0000 | +-- | memory/innodb/log0log | 9 | 8397152 | 933016.8889 | 9 | 8397152 | 933016.8889 | +-- | memory/mysys/KEY_CACHE | 3 | 8390792 | 2796930.6667 | 3 | 8390792 | 2796930.6667 | +-- | memory/innodb/hash0hash | 27 | 4962992 | 183814.5185 | 27 | 7173904 | 265700.1481 | +-- | memory/innodb/os0event | 24998 | 4199664 | 168.0000 | 24998 | 4199664 | 168.0000 | +-- ... +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$memory_global_by_current_bytes ( + event_name, + current_count, + current_alloc, + current_avg_alloc, + high_count, + high_alloc, + high_avg_alloc +) AS +SELECT event_name, + current_count_used AS current_count, + current_number_of_bytes_used AS current_alloc, + IFNULL(current_number_of_bytes_used / NULLIF(current_count_used, 0), 0) AS current_avg_alloc, + high_count_used AS high_count, + high_number_of_bytes_used AS high_alloc, + IFNULL(high_number_of_bytes_used / NULLIF(high_count_used, 0), 0) AS high_avg_alloc + FROM performance_schema.memory_summary_global_by_event_name + WHERE current_number_of_bytes_used > 0 + ORDER BY current_number_of_bytes_used DESC; diff --git a/scripts/sys_schema/views/p_s/x_memory_global_total.sql b/scripts/sys_schema/views/p_s/x_memory_global_total.sql new file mode 100644 index 00000000..9fe7e7b1 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_memory_global_total.sql @@ -0,0 +1,37 @@ +-- 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: x$memory_global_total +-- +-- Shows the total memory usage within the server globally +-- +-- mysql> select * from x$memory_global_total; +-- +-----------------+ +-- | total_allocated | +-- +-----------------+ +-- | 1420023 | +-- +-----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$memory_global_total ( + total_allocated +) AS +SELECT SUM(CURRENT_NUMBER_OF_BYTES_USED) total_allocated + FROM performance_schema.memory_summary_global_by_event_name; diff --git a/scripts/sys_schema/views/p_s/x_processlist.sql b/scripts/sys_schema/views/p_s/x_processlist.sql new file mode 100644 index 00000000..8f39918d --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_processlist.sql @@ -0,0 +1,108 @@ +-- 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: x$processlist +-- +-- A detailed non-blocking processlist view to replace +-- [INFORMATION_SCHEMA. | SHOW FULL] PROCESSLIST +-- +-- mysql> select * from x$processlist where conn_id is not null\G +-- *************************** 1. row *************************** +-- thd_id: 23 +-- conn_id: 4 +-- user: msandbox@localhost +-- db: test +-- command: Query +-- state: altering table +-- time: 19 +-- current_statement: alter table t1 add column j int +-- statement_latency: 19466744276374 +-- lock_latency: 539307000000 +-- rows_examined: 0 +-- rows_sent: 0 +-- rows_affected: 0 +-- tmp_tables: 0 +-- tmp_disk_tables: 0 +-- full_scan: NO +-- last_statement: NULL +-- last_statement_latency: NULL +-- last_wait: wait/io/file/innodb/innodb_temp_file +-- last_wait_latency: 63400681890 +-- source: row0merge.cc:780 +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$processlist ( + thd_id, + conn_id, + user, + db, + command, + state, + time, + current_statement, + statement_latency, + lock_latency, + rows_examined, + rows_sent, + rows_affected, + tmp_tables, + tmp_disk_tables, + full_scan, + last_statement, + last_statement_latency, + last_wait, + last_wait_latency, + source +) 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, + pps.processlist_info AS current_statement, + IF(esc.end_event_id IS NULL, + esc.timer_wait, + NULL) AS statement_latency, + esc.lock_time AS lock_latency, + esc.rows_examined AS rows_examined, + esc.rows_sent AS rows_sent, + esc.rows_affected AS 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, + IF(esc.end_event_id IS NOT NULL, + esc.sql_text, + NULL) AS last_statement, + IF(esc.end_event_id IS NOT NULL, + esc.timer_wait, + NULL) AS last_statement_latency, + ewc.event_name AS last_wait, + IF(ewc.end_event_id IS NULL AND ewc.event_name IS NOT NULL, + 'Still Waiting', + 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; diff --git a/scripts/sys_schema/views/p_s/x_processlist_57.sql b/scripts/sys_schema/views/p_s/x_processlist_57.sql new file mode 100644 index 00000000..cfea37a0 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_processlist_57.sql @@ -0,0 +1,141 @@ +-- 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: x$processlist +-- +-- A detailed non-blocking processlist view to replace +-- [INFORMATION_SCHEMA. | SHOW FULL] PROCESSLIST +-- +-- Performs less locking than the legacy sources, whilst giving extra information. +-- +-- mysql> select * from sys.x$processlist where conn_id is not null and command != 'daemon' and conn_id != connection_id()\G +-- ... +-- *************************** 2. row *************************** +-- thd_id: 720 +-- conn_id: 698 +-- user: msandbox@localhost +-- db: test +-- command: Query +-- state: alter table (read PK and internal sort) +-- time: 2 +-- current_statement: alter table t1 add column l int +-- statement_latency: 2349834276374 +-- progress: 60.00 +-- lock_latency: 339707000000 +-- rows_examined: 0 +-- rows_sent: 0 +-- rows_affected: 0 +-- tmp_tables: 0 +-- tmp_disk_tables: 0 +-- full_scan: NO +-- last_statement: NULL +-- last_statement_latency: NULL +-- current_memory: 10186821 +-- last_wait: wait/io/file/innodb/innodb_data_file +-- last_wait_latency: Still Waiting +-- source: fil0fil.cc:5351 +-- trx_latency: NULL +-- trx_state: NULL +-- trx_autocommit: NULL +-- pid: 5559 +-- program_name: mysql +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$processlist ( + thd_id, + conn_id, + user, + db, + command, + state, + time, + current_statement, + statement_latency, + progress, + lock_latency, + rows_examined, + rows_sent, + rows_affected, + tmp_tables, + tmp_disk_tables, + full_scan, + last_statement, + last_statement_latency, + current_memory, + last_wait, + last_wait_latency, + source, + trx_latency, + trx_state, + trx_autocommit, + pid, + program_name +) 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, + pps.processlist_info AS current_statement, + IF(esc.end_event_id IS NULL, + esc.timer_wait, + NULL) AS statement_latency, + IF(esc.end_event_id IS NULL, + ROUND(100 * (estc.work_completed / estc.work_estimated), 2), + NULL) AS progress, + esc.lock_time AS lock_latency, + esc.rows_examined AS rows_examined, + esc.rows_sent AS rows_sent, + esc.rows_affected AS 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, + IF(esc.end_event_id IS NOT NULL, + esc.sql_text, + NULL) AS last_statement, + IF(esc.end_event_id IS NOT NULL, + esc.timer_wait, + NULL) AS last_statement_latency, + mem.current_allocated AS current_memory, + ewc.event_name AS last_wait, + IF(ewc.end_event_id IS NULL AND ewc.event_name IS NOT NULL, + 'Still Waiting', + ewc.timer_wait) last_wait_latency, + ewc.source, + etc.timer_wait AS trx_latency, + etc.state AS trx_state, + etc.autocommit AS trx_autocommit, + conattr_pid.attr_value as pid, + conattr_progname.attr_value as program_name + FROM performance_schema.threads AS pps + LEFT JOIN performance_schema.events_waits_current AS ewc USING (thread_id) + LEFT JOIN performance_schema.events_stages_current AS estc USING (thread_id) + LEFT JOIN performance_schema.events_statements_current AS esc USING (thread_id) + LEFT JOIN performance_schema.events_transactions_current AS etc USING (thread_id) + LEFT JOIN sys.x$memory_by_thread_by_current_bytes AS mem USING (thread_id) + LEFT JOIN performance_schema.session_connect_attrs AS conattr_pid + ON conattr_pid.processlist_id=pps.processlist_id and conattr_pid.attr_name='_pid' + LEFT JOIN performance_schema.session_connect_attrs AS conattr_progname + ON conattr_progname.processlist_id=pps.processlist_id and conattr_progname.attr_name='program_name' + ORDER BY pps.processlist_time DESC, last_wait_latency DESC; diff --git a/scripts/sys_schema/views/p_s/x_ps_digest_95th_percentile_by_avg_us.sql b/scripts/sys_schema/views/p_s/x_ps_digest_95th_percentile_by_avg_us.sql new file mode 100644 index 00000000..de747b87 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_ps_digest_95th_percentile_by_avg_us.sql @@ -0,0 +1,46 @@ +-- 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: x$ps_digest_95th_percentile_by_avg_us +-- +-- Helper view for statements_with_runtimes_in_95th_percentile. +-- Lists the 95th percentile runtime, for all statements +-- +-- mysql> select * from x$ps_digest_95th_percentile_by_avg_us; +-- +--------+------------+ +-- | avg_us | percentile | +-- +--------+------------+ +-- | 964 | 0.9525 | +-- +--------+------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$ps_digest_95th_percentile_by_avg_us ( + avg_us, + percentile +) AS +SELECT s2.avg_us avg_us, + IFNULL(SUM(s1.cnt)/NULLIF((SELECT COUNT(*) FROM performance_schema.events_statements_summary_by_digest), 0), 0) percentile + FROM sys.x$ps_digest_avg_latency_distribution AS s1 + JOIN sys.x$ps_digest_avg_latency_distribution AS s2 + ON s1.avg_us <= s2.avg_us + GROUP BY s2.avg_us +HAVING IFNULL(SUM(s1.cnt)/NULLIF((SELECT COUNT(*) FROM performance_schema.events_statements_summary_by_digest), 0), 0) > 0.95 + ORDER BY percentile + LIMIT 1; diff --git a/scripts/sys_schema/views/p_s/x_ps_digest_avg_latency_distribution.sql b/scripts/sys_schema/views/p_s/x_ps_digest_avg_latency_distribution.sql new file mode 100644 index 00000000..7a0b468f --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_ps_digest_avg_latency_distribution.sql @@ -0,0 +1,33 @@ +-- 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: x$ps_digest_avg_latency_distribution +-- +-- Helper view for x$ps_digest_95th_percentile_by_avg_us +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$ps_digest_avg_latency_distribution ( + cnt, + avg_us +) AS +SELECT COUNT(*) cnt, + ROUND(avg_timer_wait/1000000) AS avg_us + FROM performance_schema.events_statements_summary_by_digest + GROUP BY avg_us; diff --git a/scripts/sys_schema/views/p_s/x_ps_schema_table_statistics_io.sql b/scripts/sys_schema/views/p_s/x_ps_schema_table_statistics_io.sql new file mode 100644 index 00000000..c2c36cae --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_ps_schema_table_statistics_io.sql @@ -0,0 +1,64 @@ +-- 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: x$ps_schema_table_statistics_io +-- +-- Helper view for schema_table_statistics +-- Having this view with ALGORITHM = TEMPTABLE means MySQL can use the optimizations for +-- materialized views to improve the overall performance. +-- +-- mysql> SELECT * FROM x$ps_schema_table_statistics_io LIMIT 1\G +-- *************************** 1. row *************************** +-- table_schema: charsets +-- table_name: Index +-- count_read: 1 +-- sum_number_of_bytes_read: 18710 +-- sum_timer_read: 20229409070 +-- count_write: 0 +-- sum_number_of_bytes_write: 0 +-- sum_timer_write: 0 +-- count_misc: 2 +-- sum_timer_misc: 80768480 +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$ps_schema_table_statistics_io ( + table_schema, + table_name, + count_read, + sum_number_of_bytes_read, + sum_timer_read, + count_write, + sum_number_of_bytes_write, + sum_timer_write, + count_misc, + sum_timer_misc +) AS +SELECT extract_schema_from_file_name(file_name) AS table_schema, + extract_table_from_file_name(file_name) AS table_name, + SUM(count_read) AS count_read, + SUM(sum_number_of_bytes_read) AS sum_number_of_bytes_read, + SUM(sum_timer_read) AS sum_timer_read, + SUM(count_write) AS count_write, + SUM(sum_number_of_bytes_write) AS sum_number_of_bytes_write, + SUM(sum_timer_write) AS sum_timer_write, + SUM(count_misc) AS count_misc, + SUM(sum_timer_misc) AS sum_timer_misc + FROM performance_schema.file_summary_by_instance + GROUP BY table_schema, table_name; diff --git a/scripts/sys_schema/views/p_s/x_schema_index_statistics.sql b/scripts/sys_schema/views/p_s/x_schema_index_statistics.sql new file mode 100644 index 00000000..1ef5821f --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_schema_index_statistics.sql @@ -0,0 +1,65 @@ +-- 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: x$schema_index_statistics +-- +-- Statistics around indexes. +-- +-- Ordered by the total wait time descending - top indexes are most contended. +-- +-- mysql> SELECT * FROM x$schema_index_statistics LIMIT 5; +-- +---------------+----------------------+-------------------+---------------+----------------+---------------+----------------+--------------+----------------+--------------+----------------+ +-- | table_schema | table_name | index_name | rows_selected | select_latency | rows_inserted | insert_latency | rows_updated | update_latency | rows_deleted | delete_latency | +-- +---------------+----------------------+-------------------+---------------+----------------+---------------+----------------+--------------+----------------+--------------+----------------+ +-- | common_schema | _global_sql_tokens | PRIMARY | 1886 | 1129676730 | 0 | 0 | 0 | 0 | 1878 | 0 | +-- | common_schema | _script_statements | PRIMARY | 4606 | 4212160680 | 0 | 0 | 0 | 0 | 0 | 0 | +-- | common_schema | _global_qs_variables | declaration_depth | 256 | 1650193090 | 0 | 0 | 32 | 1372148050 | 0 | 0 | +-- | common_schema | _global_qs_variables | PRIMARY | 0 | 0 | 0 | 0 | 0 | 0 | 16 | 0 | +-- | common_schema | metadata | PRIMARY | 5 | 76730810 | 0 | 0 | 4 | 114310170 | 0 | 0 | +-- +---------------+----------------------+-------------------+---------------+----------------+---------------+----------------+--------------+----------------+--------------+----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$schema_index_statistics ( + table_schema, + table_name, + index_name, + rows_selected, + select_latency, + rows_inserted, + insert_latency, + rows_updated, + update_latency, + rows_deleted, + delete_latency +) AS +SELECT OBJECT_SCHEMA AS table_schema, + OBJECT_NAME AS table_name, + INDEX_NAME as index_name, + COUNT_FETCH AS rows_selected, + SUM_TIMER_FETCH AS select_latency, + COUNT_INSERT AS rows_inserted, + SUM_TIMER_INSERT AS insert_latency, + COUNT_UPDATE AS rows_updated, + SUM_TIMER_UPDATE AS update_latency, + COUNT_DELETE AS rows_deleted, + SUM_TIMER_INSERT AS delete_latency + FROM performance_schema.table_io_waits_summary_by_index_usage + WHERE index_name IS NOT NULL + ORDER BY sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/x_schema_table_lock_waits.sql b/scripts/sys_schema/views/p_s/x_schema_table_lock_waits.sql new file mode 100644 index 00000000..0cbf84cf --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_schema_table_lock_waits.sql @@ -0,0 +1,97 @@ +-- Copyright (c) 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: schema_table_lock_waits +-- +-- Shows sessions that are blocked waiting on table metadata locks, and +-- who is blocking them. +-- +-- mysql> select * from sys.x$schema_table_lock_waits\G +-- *************************** 1. row *************************** +-- object_schema: test +-- object_name: t +-- waiting_thread_id: 43 +-- waiting_pid: 21 +-- waiting_account: msandbox@localhost +-- waiting_lock_type: SHARED_UPGRADABLE +-- waiting_lock_duration: TRANSACTION +-- waiting_query: alter table test.t add foo int +-- waiting_query_secs: 990 +-- waiting_query_rows_affected: 0 +-- waiting_query_rows_examined: 0 +-- blocking_thread_id: 42 +-- blocking_pid: 20 +-- blocking_account: msandbox@localhost +-- blocking_lock_type: SHARED_NO_READ_WRITE +-- blocking_lock_duration: TRANSACTION +-- sql_kill_blocking_query: KILL QUERY 20 +-- sql_kill_blocking_connection: KILL 20 +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$schema_table_lock_waits ( + object_schema, + object_name, + waiting_thread_id, + waiting_pid, + waiting_account, + waiting_lock_type, + waiting_lock_duration, + waiting_query, + waiting_query_secs, + waiting_query_rows_affected, + waiting_query_rows_examined, + blocking_thread_id, + blocking_pid, + blocking_account, + blocking_lock_type, + blocking_lock_duration, + sql_kill_blocking_query, + sql_kill_blocking_connection +) AS +SELECT g.object_schema AS object_schema, + g.object_name AS object_name, + pt.thread_id AS waiting_thread_id, + pt.processlist_id AS waiting_pid, + sys.ps_thread_account(p.owner_thread_id) AS waiting_account, + p.lock_type AS waiting_lock_type, + p.lock_duration AS waiting_lock_duration, + pt.processlist_info AS waiting_query, + pt.processlist_time AS waiting_query_secs, + ps.rows_affected AS waiting_query_rows_affected, + ps.rows_examined AS waiting_query_rows_examined, + gt.thread_id AS blocking_thread_id, + gt.processlist_id AS blocking_pid, + sys.ps_thread_account(g.owner_thread_id) AS blocking_account, + g.lock_type AS blocking_lock_type, + g.lock_duration AS blocking_lock_duration, + CONCAT('KILL QUERY ', gt.processlist_id) AS sql_kill_blocking_query, + CONCAT('KILL ', gt.processlist_id) AS sql_kill_blocking_connection + FROM performance_schema.metadata_locks g + INNER JOIN performance_schema.metadata_locks p + ON g.object_type = p.object_type + AND g.object_schema = p.object_schema + AND g.object_name = p.object_name + AND g.lock_status = 'GRANTED' + AND p.lock_status = 'PENDING' + INNER JOIN performance_schema.threads gt ON g.owner_thread_id = gt.thread_id + INNER JOIN performance_schema.threads pt ON p.owner_thread_id = pt.thread_id + LEFT JOIN performance_schema.events_statements_current gs ON g.owner_thread_id = gs.thread_id + LEFT JOIN performance_schema.events_statements_current ps ON p.owner_thread_id = ps.thread_id + WHERE g.object_type = 'TABLE'; diff --git a/scripts/sys_schema/views/p_s/x_schema_table_statistics.sql b/scripts/sys_schema/views/p_s/x_schema_table_statistics.sql new file mode 100644 index 00000000..b131200c --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_schema_table_statistics.sql @@ -0,0 +1,94 @@ +-- 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: x$schema_table_statistics +-- +-- Statistics around tables. +-- +-- Ordered by the total wait time descending - top tables are most contended. +-- +-- mysql> select * from x$schema_table_statistics\G +-- *************************** 1. row *************************** +-- table_schema: sys +-- table_name: sys_config +-- total_latency: 0 +-- rows_fetched: 0 +-- fetch_latency: 0 +-- rows_inserted: 0 +-- insert_latency: 0 +-- rows_updated: 0 +-- update_latency: 0 +-- rows_deleted: 0 +-- delete_latency: 0 +-- io_read_requests: 8 +-- io_read: 2336 +-- io_read_latency: 727319710 +-- io_write_requests: 0 +-- io_write: 0 +-- io_write_latency: 0 +-- io_misc_requests: 10 +-- io_misc_latency: 126879350 +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$schema_table_statistics ( + table_schema, + table_name, + total_latency, + rows_fetched, + fetch_latency, + rows_inserted, + insert_latency, + rows_updated, + update_latency, + rows_deleted, + delete_latency, + io_read_requests, + io_read, + io_read_latency, + io_write_requests, + io_write, + io_write_latency, + io_misc_requests, + io_misc_latency +) AS +SELECT pst.object_schema AS table_schema, + pst.object_name AS table_name, + pst.sum_timer_wait AS total_latency, + pst.count_fetch AS rows_fetched, + pst.sum_timer_fetch AS fetch_latency, + pst.count_insert AS rows_inserted, + pst.sum_timer_insert AS insert_latency, + pst.count_update AS rows_updated, + pst.sum_timer_update AS update_latency, + pst.count_delete AS rows_deleted, + pst.sum_timer_delete AS delete_latency, + fsbi.count_read AS io_read_requests, + fsbi.sum_number_of_bytes_read AS io_read, + fsbi.sum_timer_read AS io_read_latency, + fsbi.count_write AS io_write_requests, + fsbi.sum_number_of_bytes_write AS io_write, + fsbi.sum_timer_write AS io_write_latency, + fsbi.count_misc AS io_misc_requests, + fsbi.sum_timer_misc AS io_misc_latency + FROM performance_schema.table_io_waits_summary_by_table AS pst + LEFT JOIN x$ps_schema_table_statistics_io AS fsbi + ON pst.object_schema = fsbi.table_schema + AND pst.object_name = fsbi.table_name + ORDER BY pst.sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/x_schema_table_statistics_with_buffer.sql b/scripts/sys_schema/views/p_s/x_schema_table_statistics_with_buffer.sql new file mode 100644 index 00000000..a573c288 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_schema_table_statistics_with_buffer.sql @@ -0,0 +1,122 @@ +-- 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: x$schema_table_statistics_with_buffer +-- +-- Statistics around tables. +-- +-- Ordered by the total wait time descending - top tables are most contended. +-- +-- More statistics such as caching stats for the InnoDB buffer pool with InnoDB tables +-- +-- mysql> SELECT * FROM x$schema_table_statistics_with_buffer LIMIT 1\G +-- *************************** 1. row *************************** +-- table_schema: common_schema +-- table_name: help_content +-- rows_fetched: 0 +-- fetch_latency: 0 +-- rows_inserted: 169 +-- insert_latency: 409815527680 +-- rows_updated: 0 +-- update_latency: 0 +-- rows_deleted: 0 +-- delete_latency: 0 +-- io_read_requests: 14 +-- io_read: 1180 +-- io_read_latency: 52406770 +-- io_write_requests: 131 +-- io_write: 11719246 +-- io_write_latency: 133726902790 +-- io_misc_requests: 61 +-- io_misc_latency: 209081089750 +-- innodb_buffer_allocated: 688128 +-- innodb_buffer_data: 423667 +-- innodb_buffer_pages: 42 +-- innodb_buffer_pages_hashed: 42 +-- innodb_buffer_pages_old: 42 +-- innodb_buffer_rows_cached: 210 +-- + +DELIMITER $$ +BEGIN NOT ATOMIC +DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN END; + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$schema_table_statistics_with_buffer ( + table_schema, + table_name, + rows_fetched, + fetch_latency, + rows_inserted, + insert_latency, + rows_updated, + update_latency, + rows_deleted, + delete_latency, + io_read_requests, + io_read, + io_read_latency, + io_write_requests, + io_write, + io_write_latency, + io_misc_requests, + io_misc_latency, + innodb_buffer_allocated, + innodb_buffer_data, + innodb_buffer_free, + innodb_buffer_pages, + innodb_buffer_pages_hashed, + innodb_buffer_pages_old, + innodb_buffer_rows_cached +) AS +SELECT pst.object_schema AS table_schema, + pst.object_name AS table_name, + pst.count_fetch AS rows_fetched, + pst.sum_timer_fetch AS fetch_latency, + pst.count_insert AS rows_inserted, + pst.sum_timer_insert AS insert_latency, + pst.count_update AS rows_updated, + pst.sum_timer_update AS update_latency, + pst.count_delete AS rows_deleted, + pst.sum_timer_delete AS delete_latency, + fsbi.count_read AS io_read_requests, + fsbi.sum_number_of_bytes_read AS io_read, + fsbi.sum_timer_read AS io_read_latency, + fsbi.count_write AS io_write_requests, + fsbi.sum_number_of_bytes_write AS io_write, + fsbi.sum_timer_write AS io_write_latency, + fsbi.count_misc AS io_misc_requests, + fsbi.sum_timer_misc AS io_misc_latency, + ibp.allocated AS innodb_buffer_allocated, + ibp.data AS innodb_buffer_data, + (ibp.allocated - ibp.data) AS innodb_buffer_free, + ibp.pages AS innodb_buffer_pages, + ibp.pages_hashed AS innodb_buffer_pages_hashed, + ibp.pages_old AS innodb_buffer_pages_old, + ibp.rows_cached AS innodb_buffer_rows_cached + FROM performance_schema.table_io_waits_summary_by_table AS pst + LEFT JOIN x$ps_schema_table_statistics_io AS fsbi + ON pst.object_schema = fsbi.table_schema + AND pst.object_name = fsbi.table_name + LEFT JOIN sys.x$innodb_buffer_stats_by_table AS ibp + ON pst.object_schema = ibp.object_schema + AND pst.object_name = ibp.object_name + ORDER BY pst.sum_timer_wait DESC; +END$$ +DELIMITER ; diff --git a/scripts/sys_schema/views/p_s/x_schema_tables_with_full_table_scans.sql b/scripts/sys_schema/views/p_s/x_schema_tables_with_full_table_scans.sql new file mode 100644 index 00000000..d5868bf1 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_schema_tables_with_full_table_scans.sql @@ -0,0 +1,51 @@ +-- 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: x$schema_tables_with_full_table_scans +-- +-- Find tables that are being accessed by full table scans +-- ordering by the number of rows scanned descending. +-- +-- mysql> select * from x$schema_tables_with_full_table_scans limit 5; +-- +--------------------+------------------------------+-------------------+----------------+ +-- | object_schema | object_name | rows_full_scanned | latency | +-- +--------------------+------------------------------+-------------------+----------------+ +-- | mem30__instruments | fsstatistics | 10207042 | 13098927688488 | +-- | mem30__instruments | preparedstatementapidata | 436428 | 973274338980 | +-- | mem30__instruments | mysqlprocessactivity | 411702 | 282072434940 | +-- | mem30__instruments | querycachequeriesincachedata | 374011 | 767152380564 | +-- | mem30__instruments | rowaccessesdata | 322321 | 1547594778456 | +-- +--------------------+------------------------------+-------------------+----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$schema_tables_with_full_table_scans ( + object_schema, + object_name, + rows_full_scanned, + latency +) AS +SELECT object_schema, + object_name, + count_read AS rows_full_scanned, + sum_timer_wait AS latency + FROM performance_schema.table_io_waits_summary_by_index_usage + WHERE index_name IS NULL + AND count_read > 0 + ORDER BY count_read DESC; diff --git a/scripts/sys_schema/views/p_s/x_sessions.sql b/scripts/sys_schema/views/p_s/x_sessions.sql new file mode 100644 index 00000000..e320777f --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_sessions.sql @@ -0,0 +1,63 @@ +-- 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: x$session +-- +-- Filter sys.processlist to only show user sessions and not background threads. +-- This is a non-blocking closer replacement to +-- [INFORMATION_SCHEMA. | SHOW FULL] PROCESSLIST +-- +-- Performs less locking than the legacy sources, whilst giving extra information. +-- +-- mysql> select * from sys.x$session\G +-- *************************** 1. row *************************** +-- thd_id: 24 +-- conn_id: 2 +-- user: root@localhost +-- db: sys +-- command: Query +-- state: Sending data +-- time: 0 +-- current_statement: select * from sys.x$session +-- statement_latency: 16285980000 +-- progress: NULL +-- lock_latency: 15450000000 +-- rows_examined: 0 +-- rows_sent: 0 +-- rows_affected: 0 +-- tmp_tables: 4 +-- tmp_disk_tables: 1 +-- full_scan: YES +-- last_statement: NULL +-- last_statement_latency: NULL +-- current_memory: 3383772 +-- last_wait: wait/synch/mutex/innodb/trx_mutex +-- last_wait_latency: 56550 +-- source: trx0trx.h:1520 +-- trx_latency: 17893350207000 +-- trx_state: ACTIVE +-- trx_autocommit: NO +-- pid: 5559 +-- program_name: mysql +-- + +CREATE OR REPLACE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$session + AS +SELECT * FROM sys.x$processlist +WHERE conn_id IS NOT NULL AND command != 'Daemon'; diff --git a/scripts/sys_schema/views/p_s/x_statement_analysis.sql b/scripts/sys_schema/views/p_s/x_statement_analysis.sql new file mode 100644 index 00000000..754c073c --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_statement_analysis.sql @@ -0,0 +1,103 @@ +-- 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: x$statement_analysis +-- +-- Lists a normalized statement view with aggregated statistics, +-- mimics the MySQL Enterprise Monitor Query Analysis view, +-- ordered by the total execution time per normalized statement +-- +-- mysql> select * from x$statement_analysis limit 1\G +-- *************************** 1. row *************************** +-- query: SELECT * FROM `schema_object_overview` SELECT `information_schema` . `routines` -- truncated +-- db: sys +-- full_scan: * +-- exec_count: 2 +-- err_count: 0 +-- warn_count: 0 +-- total_latency: 16751388791000 +-- max_latency: 16566171163000 +-- avg_latency: 8375694395000 +-- lock_latency: 16686483000000 +-- rows_sent: 84 +-- rows_sent_avg: 42 +-- rows_examined: 20012 +-- rows_examined_avg: 10006 +-- rows_affected: 0 +-- rows_affected_avg: 0 +-- tmp_tables: 378 +-- tmp_disk_tables: 66 +-- rows_sorted: 168 +-- sort_merge_passes: 0 +-- digest: 54f9bd520f0bbf15db0c2ed93386bec9 +-- first_seen: 2014-03-07 13:13:41 +-- last_seen: 2014-03-07 13:13:48 +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$statement_analysis ( + query, + db, + full_scan, + exec_count, + err_count, + warn_count, + total_latency, + max_latency, + avg_latency, + lock_latency, + rows_sent, + rows_sent_avg, + rows_examined, + rows_examined_avg, + rows_affected, + rows_affected_avg, + tmp_tables, + tmp_disk_tables, + rows_sorted, + sort_merge_passes, + digest, + first_seen, + last_seen +) AS +SELECT DIGEST_TEXT AS query, + SCHEMA_NAME AS db, + IF(SUM_NO_GOOD_INDEX_USED > 0 OR SUM_NO_INDEX_USED > 0, '*', '') AS full_scan, + COUNT_STAR AS exec_count, + SUM_ERRORS AS err_count, + SUM_WARNINGS AS warn_count, + SUM_TIMER_WAIT AS total_latency, + MAX_TIMER_WAIT AS max_latency, + AVG_TIMER_WAIT AS avg_latency, + SUM_LOCK_TIME AS lock_latency, + SUM_ROWS_SENT AS rows_sent, + ROUND(IFNULL(SUM_ROWS_SENT / NULLIF(COUNT_STAR, 0), 0)) AS rows_sent_avg, + SUM_ROWS_EXAMINED AS rows_examined, + ROUND(IFNULL(SUM_ROWS_EXAMINED / NULLIF(COUNT_STAR, 0), 0)) AS rows_examined_avg, + SUM_ROWS_AFFECTED AS rows_affected, + ROUND(IFNULL(SUM_ROWS_AFFECTED / NULLIF(COUNT_STAR, 0), 0)) AS rows_affected_avg, + SUM_CREATED_TMP_TABLES AS tmp_tables, + SUM_CREATED_TMP_DISK_TABLES AS tmp_disk_tables, + SUM_SORT_ROWS AS rows_sorted, + SUM_SORT_MERGE_PASSES AS sort_merge_passes, + DIGEST AS digest, + FIRST_SEEN AS first_seen, + LAST_SEEN as last_seen + FROM performance_schema.events_statements_summary_by_digest +ORDER BY SUM_TIMER_WAIT DESC; diff --git a/scripts/sys_schema/views/p_s/x_statements_with_errors_or_warnings.sql b/scripts/sys_schema/views/p_s/x_statements_with_errors_or_warnings.sql new file mode 100644 index 00000000..aa87cf6e --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_statements_with_errors_or_warnings.sql @@ -0,0 +1,64 @@ +-- 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: x$statements_with_errors_or_warnings +-- +-- Lists all normalized statements that have raised errors or warnings. +-- +-- mysql> select * from x$statements_with_errors_or_warnings LIMIT 1\G +-- *************************** 1. row *************************** +-- query: CREATE OR REPLACE ALGORITHM = TEMPTABLE DEFINER = ? @ ? SQL SECURITY INVOKER VIEW ... truncated +-- db: sys +-- exec_count: 2 +-- errors: 1 +-- error_pct: 50.0000 +-- warnings: 0 +-- warning_pct: 0.0000 +-- first_seen: 2014-03-07 12:56:54 +-- last_seen: 2014-03-07 13:01:01 +-- digest: 943a788859e623d5f7798ba0ae0fd8a9 +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$statements_with_errors_or_warnings ( + query, + db, + exec_count, + errors, + error_pct, + warnings, + warning_pct, + first_seen, + last_seen, + digest +) AS +SELECT DIGEST_TEXT AS query, + SCHEMA_NAME as db, + COUNT_STAR AS exec_count, + SUM_ERRORS AS errors, + IFNULL(SUM_ERRORS / NULLIF(COUNT_STAR, 0), 0) * 100 as error_pct, + SUM_WARNINGS AS warnings, + IFNULL(SUM_WARNINGS / NULLIF(COUNT_STAR, 0), 0) * 100 as warning_pct, + FIRST_SEEN as first_seen, + LAST_SEEN as last_seen, + DIGEST AS digest + FROM performance_schema.events_statements_summary_by_digest + WHERE SUM_ERRORS > 0 + OR SUM_WARNINGS > 0 +ORDER BY SUM_ERRORS DESC, SUM_WARNINGS DESC; diff --git a/scripts/sys_schema/views/p_s/x_statements_with_full_table_scans.sql b/scripts/sys_schema/views/p_s/x_statements_with_full_table_scans.sql new file mode 100644 index 00000000..cd4d653f --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_statements_with_full_table_scans.sql @@ -0,0 +1,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: x$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 x$statements_with_full_table_scans limit 1\G +-- *************************** 1. row *************************** +-- query: SELECT * FROM `schema_object_overview` SELECT `information_schema` . `routines` . `ROUTINE_SCHEMA` // truncated +-- db: sys +-- exec_count: 2 +-- total_latency: 16751388791000 +-- no_index_used_count: 2 +-- no_good_index_used_count: 0 +-- no_index_used_pct: 100 +-- rows_sent: 84 +-- rows_examined: 20012 +-- rows_sent_avg: 42 +-- rows_examined_avg: 10006 +-- first_seen: 2014-03-07 13:13:41 +-- last_seen: 2014-03-07 13:13:48 +-- digest: 54f9bd520f0bbf15db0c2ed93386bec9 +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$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 DIGEST_TEXT AS query, + SCHEMA_NAME as db, + COUNT_STAR AS exec_count, + 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; diff --git a/scripts/sys_schema/views/p_s/x_statements_with_runtimes_in_95th_percentile.sql b/scripts/sys_schema/views/p_s/x_statements_with_runtimes_in_95th_percentile.sql new file mode 100644 index 00000000..6281d375 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_statements_with_runtimes_in_95th_percentile.sql @@ -0,0 +1,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: x$statements_with_runtimes_in_95th_percentile +-- +-- List all statements whose average runtime, in microseconds, is in the top 95th percentile. +-- +-- mysql> SELECT * FROM x$statements_with_runtimes_in_95th_percentile LIMIT 1\G +-- *************************** 1. row *************************** +-- query: SELECT `e` . `round_robin_bin` AS `round1_1706_0_` , `e` . `id` AS `id1706_0_` , `e` . `timestamp` AS `timestamp1706_0_` , ... truncated +-- db: mem +-- full_scan: * +-- exec_count: 14 +-- err_count: 0 +-- warn_count: 0 +-- total_latency: 43961670267000 +-- max_latency: 6686877140000 +-- avg_latency: 3140119304000 +-- rows_sent: 11 +-- rows_sent_avg: 1 +-- rows_examined: 253170 +-- rows_examined_avg: 18084 +-- first_seen: 2013-12-04 20:05:01 +-- last_seen: 2013-12-04 20:06:34 +-- digest: 29ba002bf039bb6439357a10134407de +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$statements_with_runtimes_in_95th_percentile ( + query, + db, + full_scan, + exec_count, + err_count, + warn_count, + total_latency, + max_latency, + avg_latency, + rows_sent, + rows_sent_avg, + rows_examined, + rows_examined_avg, + first_seen, + last_seen, + digest +) AS +SELECT DIGEST_TEXT AS query, + SCHEMA_NAME AS db, + IF(SUM_NO_GOOD_INDEX_USED > 0 OR SUM_NO_INDEX_USED > 0, '*', '') AS full_scan, + COUNT_STAR AS exec_count, + SUM_ERRORS AS err_count, + SUM_WARNINGS AS warn_count, + SUM_TIMER_WAIT AS total_latency, + MAX_TIMER_WAIT AS max_latency, + AVG_TIMER_WAIT AS avg_latency, + SUM_ROWS_SENT AS rows_sent, + ROUND(IFNULL(SUM_ROWS_SENT / NULLIF(COUNT_STAR, 0), 0)) AS rows_sent_avg, + SUM_ROWS_EXAMINED AS rows_examined, + ROUND(IFNULL(SUM_ROWS_EXAMINED / NULLIF(COUNT_STAR, 0), 0)) 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 stmts + JOIN sys.x$ps_digest_95th_percentile_by_avg_us AS top_percentile + ON ROUND(stmts.avg_timer_wait/1000000) >= top_percentile.avg_us + ORDER BY AVG_TIMER_WAIT DESC; diff --git a/scripts/sys_schema/views/p_s/x_statements_with_sorting.sql b/scripts/sys_schema/views/p_s/x_statements_with_sorting.sql new file mode 100644 index 00000000..a168d19d --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_statements_with_sorting.sql @@ -0,0 +1,73 @@ +-- 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: x$statements_with_sorting +-- +-- Lists all normalized statements that have done sorts, +-- ordered by total_latency descending. +-- +-- mysql> select * from x$statements_with_sorting\G +-- *************************** 1. row *************************** +-- query: SELECT * FROM `schema_object_overview` SELECT `information_schema` . `routines` . `ROUTINE_SCHEMA` AS ... truncated +-- db: sys +-- exec_count: 2 +-- total_latency: 16751388791000 +-- sort_merge_passes: 0 +-- avg_sort_merges: 0 +-- sorts_using_scans: 12 +-- sort_using_range: 0 +-- rows_sorted: 168 +-- avg_rows_sorted: 84 +-- first_seen: 2014-03-07 13:13:41 +-- last_seen: 2014-03-07 13:13:48 +-- digest: 54f9bd520f0bbf15db0c2ed93386bec9 +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$statements_with_sorting ( + query, + db, + exec_count, + total_latency, + sort_merge_passes, + avg_sort_merges, + sorts_using_scans, + sort_using_range, + rows_sorted, + avg_rows_sorted, + first_seen, + last_seen, + digest +) AS +SELECT DIGEST_TEXT AS query, + SCHEMA_NAME db, + COUNT_STAR AS exec_count, + SUM_TIMER_WAIT AS total_latency, + SUM_SORT_MERGE_PASSES AS sort_merge_passes, + ROUND(IFNULL(SUM_SORT_MERGE_PASSES / NULLIF(COUNT_STAR, 0), 0)) AS avg_sort_merges, + SUM_SORT_SCAN AS sorts_using_scans, + SUM_SORT_RANGE AS sort_using_range, + SUM_SORT_ROWS AS rows_sorted, + ROUND(IFNULL(SUM_SORT_ROWS / NULLIF(COUNT_STAR, 0), 0)) AS avg_rows_sorted, + FIRST_SEEN as first_seen, + LAST_SEEN as last_seen, + DIGEST AS digest + FROM performance_schema.events_statements_summary_by_digest + WHERE SUM_SORT_ROWS > 0 + ORDER BY SUM_TIMER_WAIT DESC; diff --git a/scripts/sys_schema/views/p_s/x_statements_with_temp_tables.sql b/scripts/sys_schema/views/p_s/x_statements_with_temp_tables.sql new file mode 100644 index 00000000..d8f5fa2e --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_statements_with_temp_tables.sql @@ -0,0 +1,68 @@ +-- 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: x$statements_with_temp_tables +-- +-- Lists all normalized statements that use temporary tables +-- ordered by number of on disk temporary tables descending first, +-- then by the number of memory tables. +-- +-- mysql> select * from x$statements_with_temp_tables limit 1\G +-- *************************** 1. row *************************** +-- query: SELECT * FROM `schema_object_overview` SELECT `information_schema` . `routines` . `ROUTINE_SCHEMA` AS `db` , ... truncated +-- db: sys +-- exec_count: 2 +-- total_latency: 16751388791000 +-- memory_tmp_tables: 378 +-- disk_tmp_tables: 66 +-- avg_tmp_tables_per_query: 189 +-- tmp_tables_to_disk_pct: 17 +-- first_seen: 2014-03-07 13:13:41 +-- last_seen: 2014-03-07 13:13:48 +-- digest: 54f9bd520f0bbf15db0c2ed93386bec9 +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$statements_with_temp_tables ( + query, + db, + exec_count, + total_latency, + memory_tmp_tables, + disk_tmp_tables, + avg_tmp_tables_per_query, + tmp_tables_to_disk_pct, + first_seen, + last_seen, + digest +) AS +SELECT DIGEST_TEXT AS query, + SCHEMA_NAME as db, + COUNT_STAR AS exec_count, + SUM_TIMER_WAIT as total_latency, + SUM_CREATED_TMP_TABLES AS memory_tmp_tables, + SUM_CREATED_TMP_DISK_TABLES AS disk_tmp_tables, + ROUND(IFNULL(SUM_CREATED_TMP_TABLES / NULLIF(COUNT_STAR, 0), 0)) AS avg_tmp_tables_per_query, + ROUND(IFNULL(SUM_CREATED_TMP_DISK_TABLES / NULLIF(SUM_CREATED_TMP_TABLES, 0), 0) * 100) AS tmp_tables_to_disk_pct, + FIRST_SEEN as first_seen, + LAST_SEEN as last_seen, + DIGEST AS digest + FROM performance_schema.events_statements_summary_by_digest + WHERE SUM_CREATED_TMP_TABLES > 0 +ORDER BY SUM_CREATED_TMP_DISK_TABLES DESC, SUM_CREATED_TMP_TABLES DESC; diff --git a/scripts/sys_schema/views/p_s/x_user_summary.sql b/scripts/sys_schema/views/p_s/x_user_summary.sql new file mode 100644 index 00000000..8c9f4b3b --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_user_summary.sql @@ -0,0 +1,60 @@ +-- 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: x$user_summary +-- +-- Summarizes statement activity, file IO and connections by user. +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$user_summary; +-- +------+------------+-------------------+-----------------------+-------------+----------+-----------------+---------------------+-------------------+--------------+ +-- | user | statements | statement_latency | statement_avg_latency | table_scans | file_ios | file_io_latency | current_connections | total_connections | unique_hosts | +-- +------+------------+-------------------+-----------------------+-------------+----------+-----------------+---------------------+-------------------+--------------+ +-- | root | 2925 | 239577283481000 | 81906763583.2479 | 83 | 54709 | 55605611965150 | 1 | 1 | 1 | +-- +------+------------+-------------------+-----------------------+-------------+----------+-----------------+---------------------+-------------------+--------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$user_summary ( + user, + statements, + statement_latency, + statement_avg_latency, + table_scans, + file_ios, + file_io_latency, + current_connections, + total_connections, + unique_hosts +) AS +SELECT IF(accounts.user IS NULL, 'background', accounts.user) AS user, + SUM(stmt.total) AS statements, + SUM(stmt.total_latency) AS statement_latency, + IFNULL(SUM(stmt.total_latency) / NULLIF(SUM(stmt.total), 0), 0) AS statement_avg_latency, + SUM(stmt.full_scans) AS table_scans, + SUM(io.ios) AS file_ios, + SUM(io.io_latency) AS file_io_latency, + SUM(accounts.current_connections) AS current_connections, + SUM(accounts.total_connections) AS total_connections, + COUNT(DISTINCT host) AS unique_hosts + FROM performance_schema.accounts + LEFT JOIN sys.x$user_summary_by_statement_latency AS stmt ON IF(accounts.user IS NULL, 'background', accounts.user) = stmt.user + LEFT JOIN sys.x$user_summary_by_file_io AS io ON IF(accounts.user IS NULL, 'background', accounts.user) = io.user + GROUP BY IF(accounts.user IS NULL, 'background', accounts.user); diff --git a/scripts/sys_schema/views/p_s/x_user_summary_57.sql b/scripts/sys_schema/views/p_s/x_user_summary_57.sql new file mode 100644 index 00000000..9bcaa781 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_user_summary_57.sql @@ -0,0 +1,67 @@ +-- 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: x$user_summary +-- +-- Summarizes statement activity and connections by user +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$user_summary; +-- +------+------------+-----------------+------------------+---------------------+-------------------+--------------+----------------+------------------------+ +-- | user | statements | total_latency | avg_latency | current_connections | total_connections | unique_hosts | current_memory | total_memory_allocated | +-- +------+------------+-----------------+------------------+---------------------+-------------------+--------------+----------------+------------------------+ +-- | root | 5685 | 107175100271000 | 18852260381.8821 | 1 | 1 | 1 | 1459022 | 572855680 | +-- | mark | 225 | 14489223428000 | 64396548568.8889 | 1 | 1 | 1 | 724578 | 84958286 | +-- +------+------------+-----------------+------------------+---------------------+-------------------+--------------+----------------+------------------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$user_summary ( + user, + statements, + statement_latency, + statement_avg_latency, + table_scans, + file_ios, + file_io_latency, + current_connections, + total_connections, + unique_hosts, + current_memory, + total_memory_allocated +) AS +SELECT IF(accounts.user IS NULL, 'background', accounts.user) AS user, + SUM(stmt.total) AS statements, + SUM(stmt.total_latency) AS statement_latency, + IFNULL(SUM(stmt.total_latency) / NULLIF(SUM(stmt.total), 0), 0) AS statement_avg_latency, + SUM(stmt.full_scans) AS table_scans, + SUM(io.ios) AS file_ios, + SUM(io.io_latency) AS file_io_latency, + SUM(accounts.current_connections) AS current_connections, + SUM(accounts.total_connections) AS total_connections, + COUNT(DISTINCT host) AS unique_hosts, + SUM(mem.current_allocated) AS current_memory, + SUM(mem.total_allocated) AS total_memory_allocated + FROM performance_schema.accounts + LEFT JOIN sys.x$user_summary_by_statement_latency AS stmt ON IF(accounts.user IS NULL, 'background', accounts.user) = stmt.user + LEFT JOIN sys.x$user_summary_by_file_io AS io ON IF(accounts.user IS NULL, 'background', accounts.user) = io.user + LEFT JOIN sys.x$memory_by_user_by_current_bytes mem ON IF(accounts.user IS NULL, 'background', accounts.user) = mem.user + GROUP BY IF(accounts.user IS NULL, 'background', accounts.user) + ORDER BY SUM(stmt.total_latency) DESC; diff --git a/scripts/sys_schema/views/p_s/x_user_summary_by_file_io.sql b/scripts/sys_schema/views/p_s/x_user_summary_by_file_io.sql new file mode 100644 index 00000000..0fe1f55f --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_user_summary_by_file_io.sql @@ -0,0 +1,47 @@ +-- 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: x$user_summary_by_file_io +-- +-- Summarizes file IO totals per user. +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$user_summary_by_file_io; +-- +------------+-------+----------------+ +-- | user | ios | io_latency | +-- +------------+-------+----------------+ +-- | root | 26457 | 21579585586390 | +-- | background | 1189 | 394212617370 | +-- +------------+-------+----------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$user_summary_by_file_io ( + user, + ios, + io_latency +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + SUM(count_star) AS ios, + SUM(sum_timer_wait) AS io_latency + FROM performance_schema.events_waits_summary_by_user_by_event_name + WHERE event_name LIKE 'wait/io/file/%' + GROUP BY IF(user IS NULL, 'background', user) + ORDER BY SUM(sum_timer_wait) DESC; diff --git a/scripts/sys_schema/views/p_s/x_user_summary_by_file_io_type.sql b/scripts/sys_schema/views/p_s/x_user_summary_by_file_io_type.sql new file mode 100644 index 00000000..6705ae97 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_user_summary_by_file_io_type.sql @@ -0,0 +1,66 @@ +-- 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: x$user_summary_by_file_io_type +-- +-- Summarizes file IO by event type per user. +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$user_summary_by_file_io_type; +-- +------------+--------------------------------------+-------+---------------+--------------+ +-- | user | event_name | total | latency | max_latency | +-- +------------+--------------------------------------+-------+---------------+--------------+ +-- | background | wait/io/file/sql/FRM | 871 | 168148450470 | 18482624810 | +-- | background | wait/io/file/innodb/innodb_data_file | 173 | 129564287450 | 34087423890 | +-- | background | wait/io/file/innodb/innodb_log_file | 20 | 77525706960 | 60657475320 | +-- | background | wait/io/file/myisam/dfile | 40 | 6544493800 | 4580546230 | +-- | background | wait/io/file/mysys/charset | 3 | 4793558770 | 4713476430 | +-- | background | wait/io/file/myisam/kfile | 67 | 4384332810 | 300035450 | +-- | background | wait/io/file/sql/ERRMSG | 5 | 2717434850 | 1687316280 | +-- | background | wait/io/file/sql/pid | 3 | 266301490 | 185468920 | +-- | background | wait/io/file/sql/casetest | 5 | 246814360 | 150193030 | +-- | background | wait/io/file/sql/global_ddl_log | 2 | 21236410 | 18593640 | +-- | root | wait/io/file/sql/file_parser | 1422 | 4801104756760 | 135138518970 | +-- | root | wait/io/file/sql/FRM | 865 | 85818594810 | 9812303410 | +-- | root | wait/io/file/myisam/kfile | 1073 | 37143664870 | 15793838190 | +-- | root | wait/io/file/myisam/dfile | 2991 | 25528215700 | 5252232050 | +-- | root | wait/io/file/sql/dbopt | 20 | 1067339780 | 153073310 | +-- | root | wait/io/file/sql/misc | 4 | 59713030 | 33752810 | +-- | root | wait/io/file/archive/data | 1 | 13907530 | 13907530 | +-- +------------+--------------------------------------+-------+---------------+--------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$user_summary_by_file_io_type ( + user, + event_name, + total, + latency, + max_latency +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + event_name, + count_star AS total, + sum_timer_wait AS latency, + max_timer_wait AS max_latency + FROM performance_schema.events_waits_summary_by_user_by_event_name + WHERE event_name LIKE 'wait/io/file%' + AND count_star > 0 + ORDER BY user, sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/x_user_summary_by_stages.sql b/scripts/sys_schema/views/p_s/x_user_summary_by_stages.sql new file mode 100644 index 00000000..1e94d6db --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_user_summary_by_stages.sql @@ -0,0 +1,64 @@ +-- 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: x$user_summary_by_stages +-- +-- Summarizes stages by user, ordered by user and total latency per stage. +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$user_summary_by_stages; +-- +------+--------------------------------+-------+---------------+-------------+ +-- | user | event_name | total | total_latency | avg_latency | +-- +------+--------------------------------+-------+---------------+-------------+ +-- | root | stage/sql/Opening tables | 1114 | 71919037000 | 64559000 | +-- | root | stage/sql/Creating sort index | 5 | 2245762000 | 449152000 | +-- | root | stage/sql/init | 13 | 428798000 | 32984000 | +-- | root | stage/sql/checking permissions | 13 | 363231000 | 27940000 | +-- | root | stage/sql/freeing items | 7 | 137728000 | 19675000 | +-- | root | stage/sql/statistics | 6 | 93955000 | 15659000 | +-- | root | stage/sql/preparing | 6 | 82571000 | 13761000 | +-- | root | stage/sql/optimizing | 6 | 63338000 | 10556000 | +-- | root | stage/sql/Sending data | 6 | 53400000 | 8900000 | +-- | root | stage/sql/closing tables | 7 | 46922000 | 6703000 | +-- | root | stage/sql/System lock | 6 | 40175000 | 6695000 | +-- | root | stage/sql/query end | 7 | 31723000 | 4531000 | +-- | root | stage/sql/Sorting result | 6 | 9855000 | 1642000 | +-- | root | stage/sql/end | 6 | 9556000 | 1592000 | +-- | root | stage/sql/cleaning up | 7 | 7312000 | 1044000 | +-- | root | stage/sql/executing | 6 | 6487000 | 1081000 | +-- +------+--------------------------------+-------+---------------+-------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$user_summary_by_stages ( + user, + event_name, + total, + total_latency, + avg_latency +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + event_name, + count_star AS total, + sum_timer_wait AS total_latency, + avg_timer_wait AS avg_latency + FROM performance_schema.events_stages_summary_by_user_by_event_name + WHERE sum_timer_wait != 0 + ORDER BY user, sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/x_user_summary_by_statement_latency.sql b/scripts/sys_schema/views/p_s/x_user_summary_by_statement_latency.sql new file mode 100644 index 00000000..5bc520b7 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_user_summary_by_statement_latency.sql @@ -0,0 +1,57 @@ +-- 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: x$user_summary_by_statement_latency +-- +-- Summarizes overall statement statistics by user. +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$user_summary_by_statement_latency; +-- +------+-------+-----------------+---------------+---------------+-----------+---------------+---------------+------------+ +-- | user | total | total_latency | max_latency | lock_latency | rows_sent | rows_examined | rows_affected | full_scans | +-- +------+-------+-----------------+---------------+---------------+-----------+---------------+---------------+------------+ +-- | root | 3382 | 129134039432000 | 1483246743000 | 1069831000000 | 1152 | 94286 | 150 | 92 | +-- +------+-------+-----------------+---------------+---------------+-----------+---------------+---------------+------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$user_summary_by_statement_latency ( + user, + total, + total_latency, + max_latency, + lock_latency, + rows_sent, + rows_examined, + rows_affected, + full_scans +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + SUM(count_star) AS total, + SUM(sum_timer_wait) AS total_latency, + SUM(max_timer_wait) AS max_latency, + SUM(sum_lock_time) AS lock_latency, + SUM(sum_rows_sent) AS rows_sent, + SUM(sum_rows_examined) AS rows_examined, + SUM(sum_rows_affected) AS rows_affected, + SUM(sum_no_index_used) + SUM(sum_no_good_index_used) AS full_scans + FROM performance_schema.events_statements_summary_by_user_by_event_name + GROUP BY IF(user IS NULL, 'background', user) + ORDER BY SUM(sum_timer_wait) DESC; diff --git a/scripts/sys_schema/views/p_s/x_user_summary_by_statement_type.sql b/scripts/sys_schema/views/p_s/x_user_summary_by_statement_type.sql new file mode 100644 index 00000000..e2c2c5e7 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_user_summary_by_statement_type.sql @@ -0,0 +1,64 @@ +-- 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: x$user_summary_by_statement_type +-- +-- Summarizes the types of statements executed by each user. +-- +-- When the user found is NULL, it is assumed to be a "background" thread. +-- +-- mysql> select * from x$user_summary_by_statement_type; +-- +------+----------------------+--------+-----------------+----------------+----------------+-----------+---------------+---------------+------------+ +-- | user | statement | total | total_latency | max_latency | lock_latency | rows_sent | rows_examined | rows_affected | full_scans | +-- +------+----------------------+--------+-----------------+----------------+----------------+-----------+---------------+---------------+------------+ +-- | root | create_view | 2110 | 312717366332000 | 463578029000 | 1432355000000 | 0 | 0 | 0 | 0 | +-- | root | select | 177 | 41115690428000 | 28827579292000 | 858709000000 | 5254 | 157437 | 0 | 83 | +-- | root | stmt | 6645 | 15305389969000 | 491780297000 | 0 | 0 | 0 | 7951 | 0 | +-- | root | call_procedure | 17 | 4783806053000 | 1016083397000 | 37936000000 | 0 | 0 | 19 | 0 | +-- | root | create_table | 19 | 3035120946000 | 431706815000 | 0 | 0 | 0 | 0 | 0 | +-- ... +-- +------+----------------------+--------+-----------------+----------------+----------------+-----------+---------------+---------------+------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$user_summary_by_statement_type ( + user, + statement, + total, + total_latency, + max_latency, + lock_latency, + rows_sent, + rows_examined, + rows_affected, + full_scans +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + SUBSTRING_INDEX(event_name, '/', -1) AS statement, + count_star AS total, + sum_timer_wait AS total_latency, + max_timer_wait AS max_latency, + sum_lock_time AS lock_latency, + sum_rows_sent AS rows_sent, + sum_rows_examined AS rows_examined, + sum_rows_affected AS rows_affected, + sum_no_index_used + sum_no_good_index_used AS full_scans + FROM performance_schema.events_statements_summary_by_user_by_event_name + WHERE sum_timer_wait != 0 + ORDER BY user, sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/x_wait_classes_global_by_avg_latency.sql b/scripts/sys_schema/views/p_s/x_wait_classes_global_by_avg_latency.sql new file mode 100644 index 00000000..48dabe51 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_wait_classes_global_by_avg_latency.sql @@ -0,0 +1,57 @@ +-- 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: x$wait_classes_global_by_avg_latency +-- +-- Lists the top wait classes by average latency, ignoring idle (this may be very large). +-- +-- mysql> select * from x$wait_classes_global_by_avg_latency; +-- +-------------------+---------+-------------------+-------------+--------------------+------------------+ +-- | event_class | total | total_latency | min_latency | avg_latency | max_latency | +-- +-------------------+---------+-------------------+-------------+--------------------+------------------+ +-- | idle | 4331 | 16044682716000000 | 2000000 | 3704613880397.1369 | 1593550454000000 | +-- | wait/io/file | 23037 | 20856702551880 | 0 | 905356711.0249 | 350700491310 | +-- | wait/io/table | 224924 | 719670285750 | 116870 | 3199615.3623 | 208579012460 | +-- | wait/lock/table | 6972 | 3674766030 | 109330 | 527074.8752 | 8855730 | +-- | wait/synch/rwlock | 11916 | 1273279800 | 37700 | 106854.6324 | 6838780 | +-- | wait/synch/mutex | 1031881 | 80464286240 | 56550 | 77978.2613 | 2590408470 | +-- +-------------------+---------+-------------------+-------------+--------------------+------------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$wait_classes_global_by_avg_latency ( + event_class, + total, + total_latency, + min_latency, + avg_latency, + max_latency +) AS +SELECT SUBSTRING_INDEX(event_name,'/', 3) AS event_class, + SUM(COUNT_STAR) AS total, + SUM(sum_timer_wait) AS total_latency, + MIN(min_timer_wait) AS min_latency, + IFNULL(SUM(sum_timer_wait) / NULLIF(SUM(COUNT_STAR), 0), 0) AS avg_latency, + MAX(max_timer_wait) AS max_latency + FROM performance_schema.events_waits_summary_global_by_event_name + WHERE sum_timer_wait > 0 + AND event_name != 'idle' + GROUP BY event_class + ORDER BY IFNULL(SUM(sum_timer_wait) / NULLIF(SUM(COUNT_STAR), 0), 0) DESC; + diff --git a/scripts/sys_schema/views/p_s/x_wait_classes_global_by_latency.sql b/scripts/sys_schema/views/p_s/x_wait_classes_global_by_latency.sql new file mode 100644 index 00000000..c9ac5069 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_wait_classes_global_by_latency.sql @@ -0,0 +1,56 @@ +-- 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: x$wait_classes_global_by_latency +-- +-- Lists the top wait classes by total latency, ignoring idle (this may be very large). +-- +-- mysql> SELECT * FROM x$wait_classes_global_by_latency; +-- +-------------------+---------+----------------+-------------+----------------+--------------+ +-- | event_class | total | total_latency | min_latency | avg_latency | max_latency | +-- +-------------------+---------+----------------+-------------+----------------+--------------+ +-- | wait/io/file | 29468 | 27100905420290 | 0 | 919672370.7170 | 350700491310 | +-- | wait/io/table | 224924 | 719670285750 | 116870 | 3199615.3623 | 208579012460 | +-- | wait/synch/mutex | 1532036 | 118515948070 | 56550 | 77358.4616 | 2590408470 | +-- | wait/io/socket | 1193 | 10677541030 | 0 | 8950160.1257 | 287760330 | +-- | wait/lock/table | 6972 | 3674766030 | 109330 | 527074.8752 | 8855730 | +-- | wait/synch/rwlock | 13646 | 1579833580 | 37700 | 115772.6499 | 28293850 | +-- +-------------------+---------+----------------+-------------+----------------+--------------+ +-- + +CREATE OR REPLACE + ALGORITHM = TEMPTABLE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$wait_classes_global_by_latency ( + event_class, + total, + total_latency, + min_latency, + avg_latency, + max_latency +) AS +SELECT SUBSTRING_INDEX(event_name,'/', 3) AS event_class, + SUM(COUNT_STAR) AS total, + SUM(sum_timer_wait) AS total_latency, + MIN(min_timer_wait) AS min_latency, + IFNULL(SUM(sum_timer_wait) / NULLIF(SUM(COUNT_STAR), 0), 0) AS avg_latency, + MAX(max_timer_wait) AS max_latency + FROM performance_schema.events_waits_summary_global_by_event_name + WHERE sum_timer_wait > 0 + AND event_name != 'idle' + GROUP BY SUBSTRING_INDEX(event_name,'/', 3) + ORDER BY SUM(sum_timer_wait) DESC; diff --git a/scripts/sys_schema/views/p_s/x_waits_by_host_by_latency.sql b/scripts/sys_schema/views/p_s/x_waits_by_host_by_latency.sql new file mode 100644 index 00000000..c6f55f90 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_waits_by_host_by_latency.sql @@ -0,0 +1,54 @@ +-- 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: waits_by_host_by_latency +-- +-- Lists the top wait events per host by their total latency, ignoring idle (this may be very large). +-- +-- mysql> select * from sys.x$waits_by_host_by_latency where host != 'background' limit 5; +-- +-----------+------------------------------+-------+----------------+-------------+--------------+ +-- | host | event | total | total_latency | avg_latency | max_latency | +-- +-----------+------------------------------+-------+----------------+-------------+--------------+ +-- | localhost | wait/io/file/sql/file_parser | 1388 | 14502657551590 | 10448600240 | 357364034170 | +-- | localhost | wait/io/file/sql/FRM | 167 | 361060236420 | 2162037319 | 75331088170 | +-- | localhost | wait/io/file/myisam/kfile | 410 | 322294755250 | 786084585 | 65978227120 | +-- | localhost | wait/io/file/myisam/dfile | 1327 | 307435262550 | 231676679 | 37162925800 | +-- | localhost | wait/io/file/sql/dbopt | 89 | 180341976360 | 2026314303 | 63405386850 | +-- +-----------+------------------------------+-------+----------------+-------------+--------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$waits_by_host_by_latency ( + host, + event, + total, + total_latency, + avg_latency, + max_latency +) AS +SELECT IF(host IS NULL, 'background', host) AS host, + event_name AS event, + count_star AS total, + sum_timer_wait AS total_latency, + avg_timer_wait AS avg_latency, + max_timer_wait AS max_latency + FROM performance_schema.events_waits_summary_by_host_by_event_name + WHERE event_name != 'idle' + AND sum_timer_wait > 0 + ORDER BY host, sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/x_waits_by_user_by_latency.sql b/scripts/sys_schema/views/p_s/x_waits_by_user_by_latency.sql new file mode 100644 index 00000000..42f42859 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_waits_by_user_by_latency.sql @@ -0,0 +1,65 @@ +-- 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: x$waits_by_user_by_latency +-- +-- Lists the top wait events per user by their total latency, ignoring idle (this may be very large). +-- +-- mysql> select * from x$waits_by_user_by_latency; +-- +------+-----------------------------------------------------+--------+----------------+-------------+--------------+ +-- | user | event | total | total_latency | avg_latency | max_latency | +-- +------+-----------------------------------------------------+--------+----------------+-------------+--------------+ +-- | root | wait/io/file/sql/file_parser | 13745 | 60462025415480 | 4398837508 | 231881092170 | +-- | root | wait/io/file/innodb/innodb_data_file | 4699 | 3023248450820 | 643381037 | 46928334180 | +-- | root | wait/io/file/sql/FRM | 11467 | 2600067790580 | 226743257 | 61718277920 | +-- | root | wait/io/file/myisam/dfile | 26776 | 746701506200 | 27886690 | 308785046960 | +-- | root | wait/io/file/myisam/kfile | 7126 | 462661061590 | 64925432 | 88756408780 | +-- | root | wait/io/file/sql/dbopt | 179 | 137577467690 | 768589146 | 15457199810 | +-- | root | wait/io/file/csv/metadata | 8 | 86599791590 | 10824973666 | 50322529270 | +-- | root | wait/synch/mutex/mysys/IO_CACHE::append_buffer_lock | 798080 | 66461175430 | 82940 | 161028010 | +-- | root | wait/io/file/sql/binlog | 19 | 49110632610 | 2584770058 | 9400449760 | +-- | root | wait/io/file/sql/misc | 26 | 22380676630 | 860795052 | 15298475270 | +-- | root | wait/io/file/csv/data | 4 | 297460540 | 74365135 | 111931300 | +-- | root | wait/synch/rwlock/sql/MDL_lock::rwlock | 944 | 287862120 | 304616 | 874640 | +-- | root | wait/io/file/archive/data | 4 | 82713800 | 20678450 | 40738620 | +-- | root | wait/synch/mutex/myisam/MYISAM_SHARE::intern_lock | 60 | 12211030 | 203203 | 512720 | +-- | root | wait/synch/mutex/innodb/trx_mutex | 81 | 5926440 | 73138 | 252590 | +-- +------+-----------------------------------------------------+--------+----------------+-------------+--------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$waits_by_user_by_latency ( + user, + event, + total, + total_latency, + avg_latency, + max_latency +) AS +SELECT IF(user IS NULL, 'background', user) AS user, + event_name AS event, + count_star AS total, + sum_timer_wait AS total_latency, + avg_timer_wait AS avg_latency, + max_timer_wait AS max_latency + FROM performance_schema.events_waits_summary_by_user_by_event_name + WHERE event_name != 'idle' + AND user IS NOT NULL + AND sum_timer_wait > 0 + ORDER BY user, sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/p_s/x_waits_global_by_latency.sql b/scripts/sys_schema/views/p_s/x_waits_global_by_latency.sql new file mode 100644 index 00000000..9b3ff819 --- /dev/null +++ b/scripts/sys_schema/views/p_s/x_waits_global_by_latency.sql @@ -0,0 +1,52 @@ +-- 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: x$waits_global_by_latency +-- +-- Lists the top wait events by their total latency, ignoring idle (this may be very large). +-- +-- mysql> select * from x$waits_global_by_latency limit 5; +-- +--------------------------------------+-------+---------------+-------------+--------------+ +-- | event | total | total_latency | avg_latency | max_latency | +-- +--------------------------------------+-------+---------------+-------------+--------------+ +-- | wait/io/file/sql/file_parser | 679 | 3536136351540 | 5207858773 | 129860439800 | +-- | wait/io/file/innodb/innodb_data_file | 195 | 848170566100 | 4349592637 | 350700491310 | +-- | wait/io/file/sql/FRM | 1355 | 400428476500 | 295518990 | 44823120940 | +-- | wait/io/file/innodb/innodb_log_file | 20 | 54298899070 | 2714944765 | 30108124800 | +-- | wait/io/file/mysys/charset | 3 | 24244722970 | 8081574072 | 24151547420 | +-- +--------------------------------------+-------+---------------+-------------+--------------+ +-- + +CREATE OR REPLACE + ALGORITHM = MERGE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW x$waits_global_by_latency ( + events, + total, + total_latency, + avg_latency, + max_latency +) AS +SELECT event_name AS event, + count_star AS total, + sum_timer_wait AS total_latency, + avg_timer_wait AS avg_latency, + max_timer_wait AS max_latency + FROM performance_schema.events_waits_summary_global_by_event_name + WHERE event_name != 'idle' + AND sum_timer_wait > 0 + ORDER BY sum_timer_wait DESC; diff --git a/scripts/sys_schema/views/version.sql b/scripts/sys_schema/views/version.sql new file mode 100644 index 00000000..a25b5315 --- /dev/null +++ b/scripts/sys_schema/views/version.sql @@ -0,0 +1,37 @@ +-- 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: version +-- +-- Shows the sys schema and mysql versions +-- +-- mysql> select * from sys.version; +-- +-------------+---------------+ +-- | sys_version | mysql_version | +-- +-------------+---------------+ +-- | 1.5.0 | 5.7.8-rc | +-- +-------------+---------------+ +-- + +CREATE OR REPLACE + DEFINER = 'mariadb.sys'@'localhost' + SQL SECURITY INVOKER +VIEW version ( + sys_version, + mysql_version +) AS +SELECT '1.5.1' AS sys_version, + version() AS mysql_version;
\ No newline at end of file |