|
13 | 13 | along with this program; if not, write to the Free Software |
14 | 14 | Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA */ |
15 | 15 |
|
| 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 | + |
16 | 48 | /* |
17 | 49 | * View: schema_table_statistics |
18 | 50 | * |
|
43 | 75 | * |
44 | 76 | */ |
45 | 77 |
|
| 78 | + |
46 | 79 | CREATE OR REPLACE |
47 | 80 | ALGORITHM = TEMPTABLE |
48 | 81 | DEFINER = 'root'@'localhost' |
@@ -88,9 +121,9 @@ SELECT pst.object_schema AS table_schema, |
88 | 121 | SUM(fsbi.count_misc) AS io_misc_requests, |
89 | 122 | sys.format_time(SUM(fsbi.sum_timer_misc)) AS io_misc_latency |
90 | 123 | 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 |
94 | 127 | GROUP BY pst.object_schema, pst.object_name |
95 | 128 | ORDER BY pst.sum_timer_wait DESC; |
96 | 129 |
|
@@ -169,8 +202,8 @@ SELECT pst.object_schema AS table_schema, |
169 | 202 | SUM(fsbi.count_misc) AS io_misc_requests, |
170 | 203 | SUM(fsbi.sum_timer_misc) AS io_misc_latency |
171 | 204 | 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 |
175 | 208 | GROUP BY pst.object_schema, pst.object_name |
176 | 209 | ORDER BY pst.sum_timer_wait DESC; |
0 commit comments