New in MySQL 5.7.7, the MySQL sys schema (originally the ps_helper project) is now included by default within the MySQL server!
For those unfamiliar with the sys
schema project, it is a database schema with a set of objects (views, stored procedures, stored functions, and table with a couple of triggers on it) that were implemented to give easy, human readable, DBA and Developer based use case access to the wealth of instrumentation data implemented primarily within Performance Schema, but also with various INFORMATION_SCHEMA tables as well.
First, what does included by default mean?
It means that when you initialize your MySQL 5.7 server for the first time, with either mysql_install_db, or the new mysqld --initialize
option, the sys
schema is added alongside the other standard schemas, nothing further for you to do, just initialize your database instance as you normally would.
When upgrading from a previous version, and running mysql_upgrade, the instance is checked to see whether the sys
schema already exists or not, and creates or upgrades the schema appropriately. The version of the sys schema bundled with 5.7.7 is 1.4.0, so if you already have that version installed, mysql_ugprade will do nothing. However, if you have a version prior to that, mysql_upgrade will re-create the schema with the updated version:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
|
$ /opt/mysql/5.7.7/bin/mysql_upgrade -u root -p -h 127.0.0.1 -P 5707 Enter password: Checking if update is needed. Checking server version. Running queries to upgrade MySQL server. Checking system database. mysql.columns_priv OK ...snip... mysql.user OK Found outdated sys schema version 1.3.0. Upgrading the sys schema. Checking databases. sys.sys_config OK Upgrade process completed successfully. Checking if update is needed. $ |
If the sys
schema exists on upgrade, but the sys
.version
view does not exist, then mysql_upgrade will return an error, as it will assume that the sys schema that is within the instance is a user created schema:
1
2
3
4
5
6
7
8
9
10
|
$ /opt/mysql/5.7.7/bin/mysql_upgrade -u root -p -h 127.0.0.1 -P 5707 Enter password: Checking if update is needed. Checking server version. Running queries to upgrade MySQL server. Checking system database. mysql.columns_priv OK ...snip... mysql.user OK Error occurred: A sys schema exists with no sys.version view. If you have a user created sys schema, this must be renamed for the upgrade to succeed. |
If you already have a schema called sys when upgrading to version 5.7.7 or later, you should ensure that it is renamed before running mysql_upgrade.
If you want to skip creating the sys schema with either mysql_install_db or mysql_upgrade, you can use the new --skip-sys-schema
option. You can always install it by hand at later time, using the $install_dir/share/mysql_sys_schema.sql file laid down with each installation (though this is not used within any of the above options, the DDL statements are compiled in for those).
After installation or upgrade, you then get access to the objects within the sys schema, enabling you to dive deeper in to the statistics needed to be able to answer some of the questions you get, or problems that you have to solve, on a day to day basis.
Questions like “Who is taking up all the resources on my database server?” can be quickly and easily answered with either the user summary views:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
|
mysql> show tables like 'user%'; +-----------------------------------+ | Tables_in_sys (user%) | +-----------------------------------+ | user_summary | | user_summary_by_file_io | | user_summary_by_file_io_type | | user_summary_by_stages | | user_summary_by_statement_latency | | user_summary_by_statement_type | +-----------------------------------+ 6 rows in set (0.00 sec) mysql> select * from user_summary\G *************************** 1. row *************************** user: msandbox statements: 5971 statement_latency: 1.20 m statement_avg_latency: 12.04 ms table_scans: 193 file_ios: 53784 file_io_latency: 15.35 m current_connections: 1 total_connections: 8 unique_hosts: 1 current_memory: 314.80 KiB total_memory_allocated: 14.85 MiB ... mysql> select * from user_summary_by_file_io_type where user = 'msandbox'; +----------+--------------------------------------+-------+-----------+-------------+ | user | event_name | total | latency | max_latency | +----------+--------------------------------------+-------+-----------+-------------+ | msandbox | wait/io/file/sql/FRM | 36929 | 21.95 s | 239.56 ms | | msandbox | wait/io/file/sql/file_parser | 1266 | 4.44 s | 250.93 ms | | msandbox | wait/io/file/innodb/innodb_data_file | 1086 | 1.35 s | 647.00 ms | | msandbox | wait/io/file/csv/metadata | 124 | 1.15 s | 192.03 ms | | msandbox | wait/io/file/myisam/kfile | 4376 | 221.53 ms | 23.71 ms | | msandbox | wait/io/file/innodb/innodb_log_file | 274 | 68.37 ms | 14.65 ms | | msandbox | wait/io/file/myisam/dfile | 3544 | 56.23 ms | 6.66 ms | | msandbox | wait/io/file/csv/data | 56 | 9.90 ms | 1.91 ms | | msandbox | wait/io/file/sql/trigger | 2 | 3.86 ms | 3.77 ms | | msandbox | wait/io/file/archive/data | 349 | 2.58 ms | 27.89 us | | msandbox | wait/io/file/sql/dbopt | 14 | 601.64 us | 117.95 us | | msandbox | wait/io/file/sql/misc | 13 | 540.14 us | 69.84 us | +----------+--------------------------------------+-------+-----------+-------------+ 12 rows in set (0.01 sec) mysql> select * from user_summary_by_statement_type where user = 'msandbox'; +----------+-------------------+-------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ | user | statement | total | total_latency | max_latency | lock_latency | rows_sent | rows_examined | rows_affected | full_scans | +----------+-------------------+-------+---------------+-------------+--------------+-----------+---------------+---------------+------------+ | msandbox | alter_table | 262 | 28.87 s | 1.54 s | 22.56 s | 0 | 0 | 640 | 0 | | msandbox | execute_sql | 398 | 23.63 s | 339.61 ms | 0 ps | 0 | 0 | 176 | 0 | | msandbox | create_view | 92 | 15.88 s | 429.34 ms | 253.04 ms | 0 | 0 | 0 | 0 | | msandbox | create_trigger | 2 | 607.76 ms | 314.93 ms | 1.30 ms | 0 | 0 | 0 | 0 | | msandbox | select | 119 | 574.95 ms | 221.74 ms | 74.07 ms | 2628 | 14354 | 0 | 68 | | msandbox | check | 63 | 543.44 ms | 286.57 ms | 540.43 ms | 0 | 0 | 0 | 0 | | msandbox | drop_view | 1 | 377.27 ms | 377.27 ms | 0 ps | 0 | 0 | 0 | 0 | | msandbox | show_tables | 17 | 280.49 ms | 59.88 ms | 1.39 ms | 1000 | 1000 | 0 | 17 | | msandbox | drop_trigger | 2 | 250.50 ms | 137.91 ms | 16.32 ms | 0 | 0 | 0 | 0 | | msandbox | set_option | 842 | 230.43 ms | 34.36 ms | 2.24 ms | 0 | 178 | 0 | 12 | | msandbox | Field List | 367 | 216.27 ms | 42.25 ms | 62.14 ms | 0 | 0 | 0 | 0 | ... |
Or similar output with “Which hosts are hitting my database server those most?” and these tables:
1
2
3
4
5
6
7
8
9
10
11
12
|
mysql> show tables like 'host%'; +-----------------------------------+ | Tables_in_sys (host%) | +-----------------------------------+ | host_summary | | host_summary_by_file_io | | host_summary_by_file_io_type | | host_summary_by_stages | | host_summary_by_statement_latency | | host_summary_by_statement_type | +-----------------------------------+ 6 rows in set (0.04 sec) |
Maybe you are ask yourself “Which objects are accessed the most, and how?”:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
|
mysql> select * from sys.schema_table_statistics limit 5\G *************************** 1. row *************************** table_schema: mem__quan table_name: normalized_statements_by_server_by_schema total_latency: 1.01 m rows_fetched: 8171 fetch_latency: 321.97 ms rows_inserted: 9524 insert_latency: 58.24 s rows_updated: 8171 update_latency: 2.16 s rows_deleted: 0 delete_latency: 0 ps io_read_requests: 37 io_read: 57.82 KiB io_read_latency: 86.55 ms io_write_requests: 354 io_write: 3.99 MiB io_write_latency: 2.40 ms io_misc_requests: 140 io_misc_latency: 500.78 ms *************************** 2. row *************************** table_schema: mem__quan table_name: normalized_statements_by_server_by_schema_data total_latency: 39.88 s rows_fetched: 285 fetch_latency: 86.42 ms rows_inserted: 8848 insert_latency: 39.01 s rows_updated: 261 update_latency: 786.48 ms rows_deleted: 0 delete_latency: 0 ps io_read_requests: 38 io_read: 66.58 KiB io_read_latency: 114.21 ms io_write_requests: 1210 io_write: 20.48 MiB io_write_latency: 160.15 ms io_misc_requests: 196 io_misc_latency: 893.47 ms ... |
Or “What statements have the highest overall latency, and what statistics did they have?”
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
|
mysql> select * from statement_analysis limit 10\G *************************** 1. row *************************** query: SELECT `t` . `THREAD_ID` AS `t ... _NUMBER_OF_BYTES_USED` ) DESC db: NULL full_scan: * exec_count: 20835 err_count: 4 warn_count: 0 total_latency: 38.96 m max_latency: 1.84 s avg_latency: 112.21 ms lock_latency: 33.91 s rows_sent: 844 rows_sent_avg: 0 rows_examined: 216255376 rows_examined_avg: 10379 rows_affected: 0 rows_affected_avg: 0 tmp_tables: 83340 tmp_disk_tables: 41666 rows_sorted: 1419984 sort_merge_passes: 0 digest: 2a8440817e00ec634e3d0b88c8e85ca4 first_seen: 2015-04-10 10:23:49 last_seen: 2015-04-10 11:11:49 *************************** 2. row *************************** query: SELECT * FROM ( SELECT digest ... _used AS `noIndexUsedCount` , db: mysql full_scan: * exec_count: 221 err_count: 0 warn_count: 73 total_latency: 30.09 m max_latency: 37.49 s avg_latency: 8.17 s lock_latency: 247.86 ms rows_sent: 43101 rows_sent_avg: 195 rows_examined: 31818247 rows_examined_avg: 143974 rows_affected: 0 rows_affected_avg: 0 tmp_tables: 663 tmp_disk_tables: 0 rows_sorted: 1555 sort_merge_passes: 0 digest: ef667dfa3f6169ffdecfd9ffb87cd10c first_seen: 2015-04-09 16:59:14 last_seen: 2015-04-10 12:57:21 |
Or “Which statements are using temporary tables on disk?”
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
|
mysql> select * from statements_with_temp_tables limit 5\G; *************************** 1. row *************************** query: SELECT `r` . `trx_wait_started ... ode` , `b` . `trx_started` AS db: NULL exec_count: 478707 total_latency: 13.43 m memory_tmp_tables: 3350949 disk_tmp_tables: 957414 avg_tmp_tables_per_query: 7 tmp_tables_to_disk_pct: 29 first_seen: 2015-04-10 09:49:18 last_seen: 2015-04-10 13:12:36 digest: 529f34e4046a3f19b7023aca37d6a394 *************************** 2. row *************************** query: SELECT `t` . `THREAD_ID` AS `t ... _NUMBER_OF_BYTES_USED` ) DESC db: NULL exec_count: 20835 total_latency: 38.96 m memory_tmp_tables: 83340 disk_tmp_tables: 41666 avg_tmp_tables_per_query: 4 tmp_tables_to_disk_pct: 50 first_seen: 2015-04-10 10:23:49 last_seen: 2015-04-10 11:11:49 digest: 2a8440817e00ec634e3d0b88c8e85ca4 ... |
Or “Which tables take the most space in my InnoDB buffer pool?”
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
|
mysql> select * from innodb_buffer_stats_by_table limit 10; +-------------------+----------------------------------------------------+------------+------------+-------+--------------+-----------+-------------+ | object_schema | object_name | allocated | data | pages | pages_hashed | pages_old | rows_cached | +-------------------+----------------------------------------------------+------------+------------+-------+--------------+-----------+-------------+ | mem__quan | normalized_statements_by_server_by_schema_data | 8.39 MiB | 10.87 MiB | 1074 | 1074 | 1074 | 36995 | | InnoDB System | SYS_TABLES | 1.70 MiB | 1.43 MiB | 109 | 109 | 109 | 4656 | | mem__advisor_text | localized_text | 1.45 MiB | 1.11 MiB | 93 | 93 | 93 | 1514 | | mysql | innodb_index_stats | 784.00 KiB | 380.36 KiB | 49 | 49 | 49 | 3182 | | mem__instruments | globaleventwaitsfilesummaryadvisor_fileioeventdata | 600.00 KiB | 792.25 KiB | 75 | 75 | 75 | 2265 | | mem__quan | example_statements | 560.00 KiB | 550.59 KiB | 70 | 70 | 70 | 1414 | | mem__bean_config | serialized_states | 480.00 KiB | 190.83 KiB | 30 | 30 | 30 | 481 | | mem__events | events | 320.00 KiB | 216.23 KiB | 20 | 20 | 20 | 169 | | InnoDB System | SYS_COLUMNS | 288.00 KiB | 203.33 KiB | 18 | 18 | 18 | 3055 | | mem__quan | normalized_statements | 288.00 KiB | 355.21 KiB | 36 | 36 | 36 | 716 | +-------------------+----------------------------------------------------+------------+------------+-------+--------------+-----------+-------------+ 10 rows in set (0.22 sec) |
“Where is all the memory going on my instance?”
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
|
mysql> select * from memory_global_by_current_bytes limit 10; +-----------------------------------------------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+ | event_name | current_count | current_alloc | current_avg_alloc | high_count | high_alloc | high_avg_alloc | +-----------------------------------------------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+ | memory/innodb/buf_buf_pool | 1 | 131.06 MiB | 131.06 MiB | 1 | 131.06 MiB | 131.06 MiB | | memory/innodb/mem0mem | 12476 | 17.17 MiB | 1.41 KiB | 13197 | 32.27 MiB | 2.50 KiB | | memory/innodb/log0log | 9 | 16.01 MiB | 1.78 MiB | 9 | 16.01 MiB | 1.78 MiB | | memory/innodb/lock0lock | 9279 | 14.41 MiB | 1.59 KiB | 9279 | 14.41 MiB | 1.59 KiB | | memory/performance_schema/events_statements_history_long | 1 | 13.50 MiB | 13.50 MiB | 1 | 13.50 MiB | 13.50 MiB | | memory/performance_schema/events_statements_summary_by_digest.tokens | 1 | 9.77 MiB | 9.77 MiB | 1 | 9.77 MiB | 9.77 MiB | | memory/performance_schema/events_statements_history_long.sqltext | 1 | 9.77 MiB | 9.77 MiB | 1 | 9.77 MiB | 9.77 MiB | | memory/performance_schema/events_statements_history_long.tokens | 1 | 9.77 MiB | 9.77 MiB | 1 | 9.77 MiB | 9.77 MiB | | memory/performance_schema/table_handles | 1 | 9.00 MiB | 9.00 MiB | 1 | 9.00 MiB | 9.00 MiB | | memory/performance_schema/events_statements_summary_by_thread_by_event_name | 1 | 8.58 MiB | 8.58 MiB | 1 | 8.58 MiB | 8.58 MiB | +-----------------------------------------------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+ |
“Which database files cause the most IO, and what kind of IO pattern do they have?”
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
|
mysql> select * from io_global_by_file_by_latency limit 10; +-----------------------------------------------------------------------------------+---------+---------------+------------+--------------+-------------+---------------+------------+--------------+ | file | total | total_latency | count_read | read_latency | count_write | write_latency | count_misc | misc_latency | +-----------------------------------------------------------------------------------+---------+---------------+------------+--------------+-------------+---------------+------------+--------------+ | @@datadir/ib_logfile0 | 70001 | 57.67 s | 4 | 12.47 us | 35507 | 3.59 s | 34490 | 54.08 s | | @@datadir/ibdata1 | 37512 | 37.15 s | 715 | 1.14 s | 32690 | 623.45 ms | 4107 | 35.38 s | | @@datadir/ib_logfile1 | 46994 | 24.88 s | 2 | 18.75 ms | 23495 | 399.44 ms | 23497 | 24.47 s | | @@datadir/mysql/proc.MYD | 3072639 | 14.14 s | 2048438 | 12.02 s | 7 | 217.13 us | 1024194 | 2.11 s | | @@datadir/mem__quan/normalized_statements_by_server_by_schema_data.ibd | 3134 | 2.59 s | 7 | 31.52 ms | 2793 | 397.90 ms | 334 | 2.16 s | | @@datadir/mem__instruments/globaleventwaitsfilesummaryadvisor_fileioeventdata.ibd | 778 | 1.50 s | 10 | 10.37 ms | 629 | 272.66 ms | 139 | 1.22 s | | @@datadir/mem__instruments/networktrafficadvisor_networktraffic.ibd | 424 | 1.30 s | 15 | 1.09 ms | 337 | 351.11 ms | 72 | 945.82 ms | | @@datadir/mem__instruments/fsstatistics.ibd | 397 | 1.21 s | 9 | 11.39 ms | 328 | 44.60 ms | 60 | 1.15 s | | @@datadir/mem__events/events.ibd | 1518 | 1.15 s | 15 | 6.11 ms | 1292 | 11.03 ms | 211 | 1.14 s | | @@datadir/mem__inventory/httpserver.ibd | 158 | 588.31 ms | 6 | 906.05 us | 98 | 650.16 us | 54 | 586.76 ms | +-----------------------------------------------------------------------------------+---------+---------------+------------+--------------+-------------+---------------+------------+--------------+ |
“Where is the time being spent the most within my instance?”
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
|
mysql (5.7.8) > select * from waits_global_by_latency limit 20; +----------------------------------------------+----------+---------------+-------------+-------------+ | events | total | total_latency | avg_latency | max_latency | +----------------------------------------------+----------+---------------+-------------+-------------+ | wait/io/table/sql/handler | 651645 | 7.54 m | 694.20 us | 2.31 s | | wait/io/socket/sql/client_connection | 8171190 | 3.74 m | 27.44 us | 215.29 ms | | wait/synch/sxlock/innodb/dict_operation_lock | 270734 | 1.60 m | 354.35 us | 1.21 s | | wait/io/file/innodb/innodb_log_file | 118289 | 1.40 m | 707.62 us | 820.19 ms | | wait/io/file/innodb/innodb_data_file | 82271 | 1.19 m | 869.42 us | 2.98 s | | wait/synch/mutex/innodb/log_sys_mutex | 4154064 | 37.93 s | 9.13 us | 238.31 ms | | wait/synch/mutex/sql/LOCK_table_cache | 4239803 | 35.55 s | 8.38 us | 13.47 ms | | wait/synch/sxlock/innodb/index_tree_rw_lock | 2447691 | 27.68 s | 11.31 us | 228.94 ms | | wait/synch/mutex/innodb/buf_pool_mutex | 3465947 | 18.26 s | 5.27 us | 2.31 s | | wait/synch/mutex/innodb/dict_sys_mutex | 1104503 | 15.95 s | 14.44 us | 1.18 s | | wait/io/file/myisam/dfile | 3185357 | 14.69 s | 4.61 us | 130.09 ms | | wait/io/file/sql/FRM | 26965 | 13.40 s | 497.05 us | 96.99 ms | | wait/synch/mutex/innodb/trx_sys_mutex | 5830470 | 10.92 s | 1.87 us | 83.22 ms | | wait/synch/mutex/innodb/lock_mutex | 1015659 | 6.13 s | 6.03 us | 81.22 ms | | wait/synch/sxlock/innodb/checkpoint_lock | 2036 | 5.19 s | 2.55 ms | 355.62 ms | | wait/synch/sxlock/innodb/fil_space_latch | 7061817 | 4.85 s | 686.52 ns | 528.87 ms | | wait/synch/mutex/sql/THD::LOCK_thd_data | 37813109 | 4.08 s | 107.82 ns | 29.66 ms | | wait/synch/sxlock/innodb/btr_search_latch | 451144 | 3.78 s | 8.39 us | 27.38 ms | | wait/synch/mutex/innodb/fil_system_mutex | 12971063 | 2.79 s | 215.27 ns | 32.92 ms | | wait/io/socket/sql/server_unix_socket | 275681 | 2.03 s | 7.35 us | 7.39 ms | +----------------------------------------------+----------+---------------+-------------+-------------+ |
Now you can answer all of these questions, and many more, with ease.
The reference documentation for sys is currently being worked on (it’s a huge job), but in the mean time, if you want to see the full power of what you get from the sys schema bundled within MySQL 5.7.7, see the README on the GitHub project.
Try it out, and give us your feedback! If you spot any bugs, please report them on http://bugs.mysql.com/ under the new “MySQL Server: SYS Schema” category.