Skip to content
This repository was archived by the owner on Aug 28, 2024. It is now read-only.

Commit 9ffcfad

Browse files
committed
Merge pull request #24 from JesperWisborgKrogh/dev/schema_table_statistics_performance
schema_table_statistics and schema_table_statistics_with_buffer performance
2 parents 4fc4310 + be13ef7 commit 9ffcfad

File tree

3 files changed

+51
-12
lines changed

3 files changed

+51
-12
lines changed

README.md

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -455,6 +455,10 @@ Statistics around tables.
455455

456456
Ordered by the total wait time descending - top tables are most contended.
457457

458+
Also includes the helper view (used by schema_table_statistics_with_buffer as well):
459+
460+
* x$ps_schema_table_statistics_io
461+
458462
##### Example
459463

460464
```SQL
@@ -490,6 +494,8 @@ Ordered by the total wait time descending - top tables are most contended.
490494

491495
More statistics such as caching stats for the InnoDB buffer pool with InnoDB tables
492496

497+
Uses the x$ps_schema_table_statistics_io helper view from schema_table_statistics.
498+
493499
##### Example
494500

495501
```SQL

views/p_s/schema_table_statistics.sql

Lines changed: 39 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -13,6 +13,38 @@
1313
along with this program; if not, write to the Free Software
1414
Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA */
1515

16+
/*
17+
* View: x$ps_schema_table_statistics_io
18+
*
19+
* Helper view for schema_table_statistics
20+
* Having this view with ALGORITHM = TEMPTABLE means MySQL can use the optimizations for
21+
* materialized views to improve the overall performance.
22+
*
23+
*/
24+
25+
CREATE OR REPLACE
26+
ALGORITHM = TEMPTABLE
27+
DEFINER = 'root'@'localhost'
28+
SQL SECURITY INVOKER
29+
VIEW x$ps_schema_table_statistics_io (
30+
table_schema,
31+
table_name,
32+
count_read,
33+
sum_number_of_bytes_read,
34+
sum_timer_read,
35+
count_write,
36+
sum_number_of_bytes_write,
37+
sum_timer_write,
38+
count_misc,
39+
sum_timer_misc
40+
) AS
41+
SELECT extract_schema_from_file_name(file_name) AS table_schema,
42+
extract_table_from_file_name(file_name) AS table_name,
43+
count_read, sum_number_of_bytes_read, sum_timer_read,
44+
count_write, sum_number_of_bytes_write, sum_timer_write,
45+
count_misc, sum_timer_misc
46+
FROM performance_schema.file_summary_by_instance;
47+
1648
/*
1749
* View: schema_table_statistics
1850
*
@@ -43,6 +75,7 @@
4375
*
4476
*/
4577

78+
4679
CREATE OR REPLACE
4780
ALGORITHM = TEMPTABLE
4881
DEFINER = 'root'@'localhost'
@@ -88,9 +121,9 @@ SELECT pst.object_schema AS table_schema,
88121
SUM(fsbi.count_misc) AS io_misc_requests,
89122
sys.format_time(SUM(fsbi.sum_timer_misc)) AS io_misc_latency
90123
FROM performance_schema.table_io_waits_summary_by_table AS pst
91-
LEFT JOIN performance_schema.file_summary_by_instance AS fsbi
92-
ON pst.object_schema = extract_schema_from_file_name(fsbi.file_name)
93-
AND pst.object_name = extract_table_from_file_name(fsbi.file_name)
124+
LEFT JOIN x$ps_schema_table_statistics_io AS fsbi
125+
ON pst.object_schema = fsbi.table_schema
126+
AND pst.object_name = fsbi.table_name
94127
GROUP BY pst.object_schema, pst.object_name
95128
ORDER BY pst.sum_timer_wait DESC;
96129

@@ -169,8 +202,8 @@ SELECT pst.object_schema AS table_schema,
169202
SUM(fsbi.count_misc) AS io_misc_requests,
170203
SUM(fsbi.sum_timer_misc) AS io_misc_latency
171204
FROM performance_schema.table_io_waits_summary_by_table AS pst
172-
LEFT JOIN performance_schema.file_summary_by_instance AS fsbi
173-
ON pst.object_schema = extract_schema_from_file_name(fsbi.file_name)
174-
AND pst.object_name = extract_table_from_file_name(fsbi.file_name)
205+
LEFT JOIN x$ps_schema_table_statistics_io AS fsbi
206+
ON pst.object_schema = fsbi.table_schema
207+
AND pst.object_name = fsbi.table_name
175208
GROUP BY pst.object_schema, pst.object_name
176209
ORDER BY pst.sum_timer_wait DESC;

views/p_s/schema_table_statistics_with_buffer.sql

Lines changed: 6 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -106,9 +106,9 @@ SELECT pst.object_schema AS table_schema,
106106
SUM(ibp.pages_old) AS innodb_buffer_pages_old,
107107
SUM(ibp.rows_cached) AS innodb_buffer_rows_cached
108108
FROM performance_schema.table_io_waits_summary_by_table AS pst
109-
LEFT JOIN performance_schema.file_summary_by_instance AS fsbi
110-
ON pst.object_schema = extract_schema_from_file_name(fsbi.file_name)
111-
AND pst.object_name = extract_table_from_file_name(fsbi.file_name)
109+
LEFT JOIN x$ps_schema_table_statistics_io AS fsbi
110+
ON pst.object_schema = fsbi.table_schema
111+
AND pst.object_name = fsbi.table_name
112112
LEFT JOIN sys.x$innodb_buffer_stats_by_table AS ibp
113113
ON pst.object_schema = ibp.object_schema
114114
AND pst.object_name = ibp.object_name
@@ -208,9 +208,9 @@ SELECT pst.object_schema AS table_schema,
208208
SUM(ibp.pages_old) AS innodb_buffer_pages_old,
209209
SUM(ibp.rows_cached) AS innodb_buffer_rows_cached
210210
FROM performance_schema.table_io_waits_summary_by_table AS pst
211-
LEFT JOIN performance_schema.file_summary_by_instance AS fsbi
212-
ON pst.object_schema = extract_schema_from_file_name(fsbi.file_name)
213-
AND pst.object_name = extract_table_from_file_name(fsbi.file_name)
211+
LEFT JOIN x$ps_schema_table_statistics_io AS fsbi
212+
ON pst.object_schema = fsbi.table_schema
213+
AND pst.object_name = fsbi.table_name
214214
LEFT JOIN sys.x$innodb_buffer_stats_by_table AS ibp
215215
ON pst.object_schema = ibp.object_schema
216216
AND pst.object_name = ibp.object_name

0 commit comments

Comments
 (0)