Chapter 20. MySQL Performance Schema

Table of Contents

20.1. Performance Schema Quick Start
20.2. Performance Schema Configuration
20.2.1. Performance Schema Build Configuration
20.2.2. Performance Schema Startup and Runtime Configuration
20.2.3. Event Collection Pre-Filtering and Post-Filtering
20.3. Performance Schema Status Monitoring
20.4. Performance Schema Event Timing
20.5. Performance Schema Event Instrument Naming Conventions
20.6. Performance Schema Table General Characteristics
20.7. Performance Schema Table Descriptions
20.7.1. Performance Schema Setup Tables
20.7.2. Performance Schema Current-Events Table
20.7.3. Performance Schema History Tables
20.7.4. Performance Schema Summary Tables
20.7.5. Performance Schema Instance Tables
20.7.6. Performance Schema Miscellaneous Tables
20.8. Performance Schema and Plugins
20.9. Performance Schema System Variables
20.10. Performance Schema Status Variables
20.11. Using Performance Schema to Diagnose Problems

MySQL Performance Schema is a feature for monitoring MySQL Server execution at a low level. Performance Schema is available as of MySQL 5.5.3 and has these characteristics:

MySQL Performance Schema is a feature for monitoring MySQL Server execution at a low level. This is a new feature. MySQL is working on enhancements and may add, change, rename, or remove parts of this feature at any time with no guarantee of backward compatibility.

Performance Schema has these characteristics:

Performance Schema is intended to provide access to useful information about server execution while having minimal impact on server performance. The implementation follows these design goals:

20.1. Performance Schema Quick Start

This section briefly introduces Performance Schema with examples that show how to use it. For additional examples, see Section 20.11, “Using Performance Schema to Diagnose Problems”.

For Performance Schema to be available, support for it must have been configured when MySQL was built. You can verify whether this is the case by checking the server's help output. If Performance Schema is available, the output will mention several variables with names that begin with performance_schema:

shell> mysqld --verbose --help
...
  --performance_schema
                      Enable the performance schema.
  --performance_schema_events_waits_history_long_size=#
                      Number of rows in EVENTS_WAITS_HISTORY_LONG.
...

If such variables do not appear in the output, your server has not been built to support Performance Schema. In this case, see Section 20.2, “Performance Schema Configuration”.

Assuming that Performance Schema is available, it is disabled by default. To enable it, start the server with the performance_schema variable enabled. For example, use these lines in your my.cnf file:

[mysqld]
performance_schema

When the server starts, it sees performance_schema and attempts to initialize Performance Schema. To verify successful initialization, use this statement:

mysql> SHOW VARIABLES LIKE 'performance_schema';
+--------------------+-------+
| Variable_name      | Value |
+--------------------+-------+
| performance_schema | ON    |
+--------------------+-------+

A value of ON means that Performance Schema initialized successfully and is ready for use. A value of OFF means that some error occurred. Check the server error log for information about what went wrong.

Performance Schema is implemented as a storage engine. If this engine is available (which you should already have checked earlier), you should see it listed with a SUPPORT value of YES in the output from the INFORMATION_SCHEMA.ENGINES table or the SHOW ENGINES statement:

mysql> SELECT * FROM INFORMATION_SCHEMA.ENGINES
    -> WHERE ENGINE='PERFORMANCE_SCHEMA'\G
*************************** 1. row ***************************
      ENGINE: PERFORMANCE_SCHEMA
     SUPPORT: YES
     COMMENT: Performance Schema
TRANSACTIONS: NO
          XA: NO
  SAVEPOINTS: NO

mysql> SHOW ENGINES\G
...
      Engine: PERFORMANCE_SCHEMA
     Support: YES
     Comment: Performance Schema
Transactions: NO
          XA: NO
  Savepoints: NO
...

The PERFORMANCE_SCHEMA storage engine operates on tables in the performance_schema database. You can make performance_schema the default database so that references to its tables need not be qualified with the database name:

mysql> USE performance_schema;

Many examples in this chapter assume that performance_schema is the default database.

Performance Schema tables are stored in the performance_schema database. Information about the structure of this database and its tables can be obtained, as for any other database, by selecting from the INFORMATION_SCHEMA database or by using SHOW statements. For example, use either of these statements to see what Performance Schema tables exist:

mysql> SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES
    -> WHERE TABLE_SCHEMA = 'performance_schema';
+----------------------------------------------+
| TABLE_NAME                                   |
+----------------------------------------------+
| COND_INSTANCES                               |
| EVENTS_WAITS_CURRENT                         |
| EVENTS_WAITS_HISTORY                         |
| EVENTS_WAITS_HISTORY_LONG                    |
| EVENTS_WAITS_SUMMARY_BY_EVENT_NAME           |
| EVENTS_WAITS_SUMMARY_BY_INSTANCE             |
| EVENTS_WAITS_SUMMARY_BY_THREAD_BY_EVENT_NAME |
| FILE_INSTANCES                               |
| FILE_SUMMARY_BY_EVENT_NAME                   |
| FILE_SUMMARY_BY_INSTANCE                     |
| MUTEX_INSTANCES                              |
| PERFORMANCE_TIMERS                           |
| PROCESSLIST                                  |
| RWLOCK_INSTANCES                             |
| SETUP_CONSUMERS                              |
| SETUP_INSTRUMENTS                            |
| SETUP_OBJECTS                                |
| SETUP_TIMERS                                 |
+----------------------------------------------+

mysql> SHOW TABLES FROM performance_schema;
+----------------------------------------------+
| Tables_in_performance_schema                 |
+----------------------------------------------+
| COND_INSTANCES                               |
| EVENTS_WAITS_CURRENT                         |
| EVENTS_WAITS_HISTORY                         |
...

The number of Performance Schema tables is expected to increase over time as implementation of additional instrumentation proceeds.

The database name performance_schema is lowercase. The names of tables in the database are uppercase. Normal case sensitivity rules apply, so on systems with case-sensitive file names, the database name and table names must be specified in the lettercase just indicated. This behavior can be modified by setting the lower_case_table_names system variable.

To see the structure of individual tables, use SHOW CREATE TABLE:

mysql> SHOW CREATE TABLE SETUP_TIMERS\G
*************************** 1. row ***************************
       Table: SETUP_TIMERS
Create Table: CREATE TABLE `SETUP_TIMERS` (
  `NAME` varchar(64) NOT NULL,
  `TIMER_NAME` enum('CYCLE','NANOSECOND','MICROSECOND','MILLISECOND','TICK')
   NOT NULL
) ENGINE=PERFORMANCE_SCHEMA DEFAULT CHARSET=utf8

Table structure is also available by selecting from tables such as INFORMATION_SCHEMA.COLUMNS or by using statements such as SHOW COLUMNS.

Tables in the performance_schema database can be grouped according to the type of information in them: Current events, event histories and summaries, object instances, and setup (configuration) information. The following examples illustrate a few uses for these tables. For detailed information about the tables in each group, see Section 20.7, “Performance Schema Table Descriptions”.

To see what the server is doing at the moment, examine the EVENTS_WAITS_CURRENT table. It contains one row per thread showing each thread's most recent monitored event:

mysql> SELECT * FROM EVENTS_WAITS_CURRENT\G
*************************** 1. row ***************************
            THREAD_ID: 0
             EVENT_ID: 5523
           EVENT_NAME: wait/synch/mutex/mysys/THR_LOCK::mutex
               SOURCE: thr_lock.c:525
          TIMER_START: 201660494489586
            TIMER_END: 201660494576112
           TIMER_WAIT: 86526
                SPINS: NULL
        OBJECT_SCHEMA: NULL
          OBJECT_NAME: NULL
          OBJECT_TYPE: NULL
OBJECT_INSTANCE_BEGIN: 142270668
     NESTING_EVENT_ID: NULL
            OPERATION: lock
      NUMBER_OF_BYTES: NULL
                FLAGS: 0
...

This event indicates that thread 0 was waiting for 86,526 picoseconds to acquire a lock on THR_LOCK::mutex, a mutex in the mysys subsystem. The first few columns provide the following information:

  • The ID columns indicate which thread the event comes from and the event number.

  • EVENT_NAME indicates what was instrumented and SOURCE indicates which source file contains the instrumented code.

  • The timer columns show when the event started and stopped and how long it took. If an event is still in progress, the TIMER_END and TIMER_WAIT values are NULL. Timer values are approximate and expressed in picoseconds. For information about timers and event time collection, see Section 20.4, “Performance Schema Event Timing”.

The history tables contain the same kind of rows as the current-events table but have more rows and show what the server has been doing “recently” rather than “currently.” The EVENTS_WAITS_HISTORY and EVENTS_WAITS_HISTORY_LONG tables contain the most recent 10 events per thread and most recent 10,000 events, respectively. For example, to see information for recent events produced by thread 13, do this:

mysql> SELECT EVENT_ID, EVENT_NAME, TIMER_WAIT
    -> FROM EVENTS_WAITS_HISTORY WHERE THREAD_ID = 13
    -> ORDER BY EVENT_ID;
+----------+-----------------------------------------+------------+
| EVENT_ID | EVENT_NAME                              | TIMER_WAIT |
+----------+-----------------------------------------+------------+
|       86 | wait/synch/mutex/mysys/THR_LOCK::mutex  |     686322 |
|       87 | wait/synch/mutex/mysys/THR_LOCK_malloc  |     320535 |
|       88 | wait/synch/mutex/mysys/THR_LOCK_malloc  |     339390 |
|       89 | wait/synch/mutex/mysys/THR_LOCK_malloc  |     377100 |
|       90 | wait/synch/mutex/sql/LOCK_plugin        |     614673 |
|       91 | wait/synch/mutex/sql/LOCK_open          |     659925 |
|       92 | wait/synch/mutex/sql/THD::LOCK_thd_data |     494001 |
|       93 | wait/synch/mutex/mysys/THR_LOCK_malloc  |     222489 |
|       94 | wait/synch/mutex/mysys/THR_LOCK_malloc  |     214947 |
|       95 | wait/synch/mutex/mysys/LOCK_alarm       |     312993 |
+----------+-----------------------------------------+------------+

As new events are added to a history table, older events are discarded if the table is full.

Summary tables provide aggregate information for all events over time. The tables in this group summarize event data in different ways. To see which instruments have been executed the most times or have taken the most wait time, sort the EVENTS_WAITS_SUMMARY_BY_EVENT_NAME table on the COUNT_STAR or SUM_TIMER_WAIT column, which correspond to a COUNT(*) or SUM(TIMER_WAIT) value, respectively, calculated over all events:

mysql> SELECT EVENT_NAME, COUNT_STAR
    -> FROM EVENTS_WAITS_SUMMARY_BY_EVENT_NAME
    -> ORDER BY COUNT_STAR DESC LIMIT 10;
+---------------------------------------------------+------------+
| EVENT_NAME                                        | COUNT_STAR |
+---------------------------------------------------+------------+
| wait/synch/mutex/mysys/THR_LOCK_malloc            |       6419 |
| wait/io/file/sql/FRM                              |        452 |
| wait/synch/mutex/sql/LOCK_plugin                  |        337 |
| wait/synch/mutex/mysys/THR_LOCK_open              |        187 |
| wait/synch/mutex/mysys/LOCK_alarm                 |        147 |
| wait/synch/mutex/sql/THD::LOCK_thd_data           |        115 |
| wait/io/file/myisam/kfile                         |        102 |
| wait/synch/mutex/sql/LOCK_global_system_variables |         89 |
| wait/synch/mutex/mysys/THR_LOCK::mutex            |         89 |
| wait/synch/mutex/sql/LOCK_open                    |         88 |
+---------------------------------------------------+------------+

mysql> SELECT EVENT_NAME, SUM_TIMER_WAIT
    -> FROM EVENTS_WAITS_SUMMARY_BY_EVENT_NAME
    -> ORDER BY SUM_TIMER_WAIT DESC LIMIT 10;
+----------------------------------------+----------------+
| EVENT_NAME                             | SUM_TIMER_WAIT |
+----------------------------------------+----------------+
| wait/io/file/sql/MYSQL_LOG             |     1599816582 |
| wait/synch/mutex/mysys/THR_LOCK_malloc |     1530083250 |
| wait/io/file/sql/binlog_index          |     1385291934 |
| wait/io/file/sql/FRM                   |     1292823243 |
| wait/io/file/myisam/kfile              |      411193611 |
| wait/io/file/myisam/dfile              |      322401645 |
| wait/synch/mutex/mysys/LOCK_alarm      |      145126935 |
| wait/io/file/sql/casetest              |      104324715 |
| wait/synch/mutex/sql/LOCK_plugin       |       86027823 |
| wait/io/file/sql/pid                   |       72591750 |
+----------------------------------------+----------------+

These results show that the THR_LOCK_malloc mutex is “hot,” both in terms of how often it is used and amount of time that threads wait attempting to acquire it.

Note

The THR_LOCK_malloc mutex is used only in debug builds. In production builds it is not hot because it is nonexistent.

Instance tables document what types of objects are instrumented. An instrumented object, when used by the server, produces an event. These tables provide event names and explanatory notes or status information. For example, the FILE_INSTANCES table lists instances of instruments for file I/O operations and their associated files:

mysql> SELECT * FROM FILE_INSTANCES\G
*************************** 1. row ***************************
 FILE_NAME: /opt/mysql-log/60500/binlog.000007
EVENT_NAME: wait/io/file/sql/binlog
OPEN_COUNT: 0
*************************** 2. row ***************************
 FILE_NAME: /opt/mysql/60500/data/mysql/tables_priv.MYI
EVENT_NAME: wait/io/file/myisam/kfile
OPEN_COUNT: 1
*************************** 3. row ***************************
 FILE_NAME: /opt/mysql/60500/data/mysql/columns_priv.MYI
EVENT_NAME: wait/io/file/myisam/kfile
OPEN_COUNT: 1
...

Setup tables are used to configure and display monitoring characteristics. For example, to see which event timer is selected, query the SETUP_TIMERS tables:

mysql> SELECT * FROM SETUP_TIMERS;
+------+------------+
| NAME | TIMER_NAME |
+------+------------+
| wait | CYCLE      |
+------+------------+

SETUP_INSTRUMENTS lists the set of instruments for which events can be collected and shows which of them are enabled:

mysql> SELECT * FROM SETUP_INSTRUMENTS;
+------------------------------------------------------------+---------+-------+
| NAME                                                       | ENABLED | TIMED |
+------------------------------------------------------------+---------+-------+
...
| wait/synch/mutex/sql/LOCK_global_read_lock                 | YES     | YES   |
| wait/synch/mutex/sql/LOCK_global_system_variables          | YES     | YES   |
| wait/synch/mutex/sql/LOCK_lock_db                          | YES     | YES   |
| wait/synch/mutex/sql/LOCK_manager                          | YES     | YES   |
...
| wait/synch/rwlock/sql/LOCK_grant                           | YES     | YES   |
| wait/synch/rwlock/sql/LOGGER::LOCK_logger                  | YES     | YES   |
| wait/synch/rwlock/sql/LOCK_sys_init_connect                | YES     | YES   |
| wait/synch/rwlock/sql/LOCK_sys_init_slave                  | YES     | YES   |
...
| wait/io/file/sql/binlog                                    | YES     | YES   |
| wait/io/file/sql/binlog_index                              | YES     | YES   |
| wait/io/file/sql/casetest                                  | YES     | YES   |
| wait/io/file/sql/dbopt                                     | YES     | YES   |
...

To understand how to interpret instrument names, see Section 20.5, “Performance Schema Event Instrument Naming Conventions”.

To control whether events are collected for an instrument, set its ENABLED value to YES or NO. For example:

mysql> UPDATE SETUP_INSTRUMENTS SET ENABLED = 'NO'
    -> WHERE NAME = 'wait/synch/mutex/sql/LOCK_mysql_create_db';

Performance Schema uses collected events to update tables in the performance_schema database, which act as “consumers” of event information. The SETUP_CONSUMERS table lists the available consumers and shows which of them are enabled:

mysql> SELECT * FROM SETUP_CONSUMERS;
+----------------------------------------------+---------+
| NAME                                         | ENABLED |
+----------------------------------------------+---------+
| events_waits_current                         | YES     |
| events_waits_history                         | YES     |
| events_waits_history_long                    | YES     |
| events_waits_summary_by_thread_by_event_name | YES     |
| events_waits_summary_by_event_name           | YES     |
| events_waits_summary_by_instance             | YES     |
| file_summary_by_event_name                   | YES     |
| file_summary_by_instance                     | YES     |
+----------------------------------------------+---------+

To control whether Performance Schema maintains a consumer as a destination for event information, set its ENABLED value.

For more information about the setup tables and how to use them to control event collection, see Section 20.2.3, “Event Collection Pre-Filtering and Post-Filtering”.

There are some miscellaneous tables that do not fall into any of the previous groups. For example, PERFORMANCE_TIMERS lists the available event timers and their characteristics. For information about timers, see Section 20.4, “Performance Schema Event Timing”.

20.2. Performance Schema Configuration

The capabilities described in this document are currently under development and are available in the source tree contained in the mysql-next-mr BZR repository. To use Performance Schema, you must create a branch (local copy) of this repository.

Create a branch of the mysql-next-mr repository. If you do not already have a BZR repository directory created, initialize it using the instructions at Section 2.10.3, “Installing from the Development Source Tree”. To create a new branch, use the following command:

shell> bzr branch lp:~mysql/mysql-server/mysql-next-mr mysql-next-mr

The command creates a local source tree in a directory named mysql-next-mr. Use a different name for the final argument if you like.

To use MySQL Performance Schema, these configuration considerations apply:

20.2.1. Performance Schema Build Configuration

For Performance Schema to be available, it must be configured into the MySQL server at build time. Binary MySQL distributions provided by Sun Microsystems, Inc. are configured to support Performance Schema. If you use a binary MySQL distribution from another provider, check with the provider whether the distribution has been appropriately configured.

If you build MySQL from a source distribution, enable Performance Schema by running configure with one of the following options:

  • The --with-perfschema or --with-plugins=perfschema option enables Performance Schema.

  • The --with-plugins=max option enables a collection of features, including Performance Schema. If you want finer control, use one of the other options.

If you specify none of the preceding options, Performance Schema is included by default. If you normally specify --with-plugins to name plugins to build, you can add perfschema or max to the list of names. For example:

shell> ./configure --with-plugins=innobase,perfschema

If you install MySQL over a previous installation that was configured without Performance Schema, run mysql_upgrade after starting the server to create the performance_schema database, and then restart the server.

To verify whether a server was built with Performance Schema support, check its help output. If Performance Schema is available, the output will mention several variables with names that begin with performance_schema:

shell> mysqld --verbose --help
...
  --performance_schema
                      Enable the performance schema.
  --performance_schema_events_waits_history_long_size=#
                      Number of rows in EVENTS_WAITS_HISTORY_LONG.
...

You can also connect to the server and look for a line that names the PERFORMANCE_SCHEMA storage engine in the output from SHOW ENGINES:

mysql> SHOW ENGINES\G
...
      Engine: PERFORMANCE_SCHEMA
     Support: YES
     Comment: Performance Schema
Transactions: NO
          XA: NO
  Savepoints: NO
...

If Performance Schema was not configured into the server at build time, no row for PERFORMANCE_SCHEMA will appear in the output from SHOW ENGINES. You might see performance_schema listed in the output from SHOW DATABASES, but it will have no tables and you will not be able to use it.

A line for PERFORMANCE_SCHEMA in the SHOW ENGINES output means that Performance Schema is available, not that it is enabled. To enable it, you must do so at server startup, as described in the next section.

20.2.2. Performance Schema Startup and Runtime Configuration

Performance Schema is disabled by default. To enable it, start the server with the performance_schema variable enabled. For example, use these lines in your my.cnf file:

[mysqld]
performance_schema

When the server starts, it writes Performance Schema status information to the error log:

  • Performance schema enabled indicates successful initialization.

  • Performance schema disabled (reason: start parameters) indicates that you did not enable Performance Schema by enabling the performance_schema variable.

  • Performance schema disabled (reason: init failed) indicates that you enabled performance_schema but some kind of error occurred that prevented Performance Schema from initializing successfully. For example, you may have specified other Performance Schema variables with values too large for memory allocation to succeed.

If the server is unable to allocate any internal buffer during Performance Schema initialization, Performance Schema disables itself and sets performance_schema to OFF, and the server runs without instrumentation.

Performance Schema includes several system variables that provide configuration information:

mysql> SHOW VARIABLES LIKE 'perf%';
+---------------------------------------------------+--------+
| Variable_name                                     | Value  |
+---------------------------------------------------+--------+
| performance_schema                                | ON     |
| performance_schema_events_waits_history_long_size | 10000  |
| performance_schema_events_waits_history_size      | 10     |
| performance_schema_max_cond_classes               | 80     |
| performance_schema_max_cond_instances             | 1000   |
| performance_schema_max_file_classes               | 50     |
| performance_schema_max_file_handles               | 32768  |
| performance_schema_max_file_instances             | 10000  |
| performance_schema_max_mutex_classes              | 200    |
| performance_schema_max_mutex_instances            | 1000   |
| performance_schema_max_rwlock_classes             | 20     |
| performance_schema_max_rwlock_instances           | 1000   |
| performance_schema_max_table_handles              | 100000 |
| performance_schema_max_table_instances            | 50000  |
| performance_schema_max_thread_classes             | 50     |
| performance_schema_max_thread_instances           | 1000   |
+---------------------------------------------------+--------+

The performance_schema variable is ON or OFF to indicate whether Performance Schema is enabled or disabled. The other variables indicate table sizes (number of rows) or memory allocation values.

To change the value of these variables, set them at server startup. For example, put the following lines in a my.cnf file to change the sizes of the history tables:

[mysqld]
performance_schema
performance_schema_events_waits_history_size=20
performance_schema_events_waits_history_long_size=15000

Performance Schema setup tables contain information about monitoring configuration:

mysql> SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES
    -> WHERE TABLE_SCHEMA = 'performance_schema'
    -> AND TABLE_NAME LIKE 'SETUP%';
+-------------------+
| TABLE_NAME        |
+-------------------+
| SETUP_CONSUMERS   |
| SETUP_INSTRUMENTS |
| SETUP_OBJECTS     |
| SETUP_TIMERS      |
+-------------------+

You can examine the contents of these tables to obtain information about Performance Schema monitoring characteristics. If you have the UPDATE privilege, you can change Performance Schema operation by modifying setup tables to affect how monitoring occurs. For additional details about these tables, see Section 20.7.1, “Performance Schema Setup Tables”.

To see which event timer is selected, query the SETUP_TIMERS tables:

mysql> SELECT * FROM SETUP_TIMERS;
+------+------------+
| NAME | TIMER_NAME |
+------+------------+
| wait | CYCLE      |
+------+------------+

The NAME value indicates the type of instrument to which the timer applies, and TIMER_NAME indicates which timer applies to those instruments. The timer applies to instruments where their name begins with a component matching the NAME value. Currently, there are only “wait” instruments, so this table has only one row and the timer applies to all instruments.

To change the timer, update the NAME value. For example, to use the NANOSECONDS timer:

mysql> UPDATE SETUP_TIMERS SET TIMER_NAME = 'NANOSECOND';

mysql> SELECT * FROM SETUP_TIMERS;
+------+------------+
| NAME | TIMER_NAME |
+------+------------+
| wait | NANOSECOND |
+------+------------+

Timers are discussed further in Section 20.4, “Performance Schema Event Timing”.

The SETUP_INSTRUMENTS and SETUP_CONSUMERS tables list the instruments for which events can be collected and the destination tables in which event information can be stored, respectively. Section 20.2.3, “Event Collection Pre-Filtering and Post-Filtering”, discusses how you can modify these tables to affect event collection.

20.2.3. Event Collection Pre-Filtering and Post-Filtering

Events are processed in a producer/consumer fashion:

  • Instrumented code is the source for events and produces events to be collected. The SETUP_INSTRUMENTS table lists the instruments for which events can be collected:

    mysql> SELECT * FROM SETUP_INSTRUMENTS;
    +------------------------------------------------------------+---------+-------+
    | NAME                                                       | ENABLED | TIMED |
    +------------------------------------------------------------+---------+-------+
    | wait/synch/mutex/sql/PAGE::lock                            | YES     | YES   |
    | wait/synch/mutex/sql/TC_LOG_MMAP::LOCK_sync                | YES     | YES   |
    | wait/synch/mutex/sql/TC_LOG_MMAP::LOCK_active              | YES     | YES   |
    | wait/synch/mutex/sql/TC_LOG_MMAP::LOCK_pool                | YES     | YES   |
    | wait/synch/mutex/sql/LOCK_des_key_file                     | YES     | YES   |
    | wait/synch/mutex/sql/MYSQL_BIN_LOG::LOCK_index             | YES     | YES   |
    | wait/synch/mutex/sql/MYSQL_BIN_LOG::LOCK_prep_xids         | YES     | YES   |
    | wait/synch/mutex/sql/Delayed_insert::mutex                 | YES     | YES   |
    ...
    
  • Performance Schema tables are the destinations for events and consume events. The SETUP_CONSUMERS table lists the destination tables in which event information can be stored:

    mysql> SELECT * FROM SETUP_CONSUMERS;
    +----------------------------------------------+---------+
    | NAME                                         | ENABLED |
    +----------------------------------------------+---------+
    | events_waits_current                         | YES     |
    | events_waits_history                         | YES     |
    | events_waits_history_long                    | YES     |
    | events_waits_summary_by_thread_by_event_name | YES     |
    | events_waits_summary_by_event_name           | YES     |
    | events_waits_summary_by_instance             | YES     |
    | file_summary_by_event_name                   | YES     |
    | file_summary_by_instance                     | YES     |
    +----------------------------------------------+---------+
    

Pre-filtering refers to modifying Performance Schema configuration so that only certain types of events are collected or collected events are used to update only certain tables. This type of filtering is done by Performance Schema and has a global effect that applies to all users.

Pre-filtering can be applied to either the producer or consumer stage of event processing by modifying the SETUP_INSTRUMENTS or SETUP_CONSUMERS table. An instrument or consumer can be enabled or disabled by by setting its ENABLED value to YES or NO. An instrument can be configured whether to collect timing information by setting its TIMED value to YES or NO.

Post-filtering refers to the use of WHERE clauses when selecting information from Performance Schema tables, to specify which of the available events you want to see. This type of filtering is performed on a per-user basis because individual users select which of the available events are of interest.

Reasons to use pre-filtering include the following:

  • Pre-filtering reduces overhead. The overhead should be minimal even with all instruments enabled, but perhaps you want to reduce it further. Or you do not care about timing events and want to disable the timing code to eliminate timing overhead.

  • You do not want to fill up the current-events or history tables with events in which you have no interest. Pre-filtering leaves more “room” in these tables for instances of rows for enabled instrument types. If you enable only file instruments with pre-filtering, no rows are collected for nonfile instruments. With post-filtering, nonfile events are collected, leaving fewer rows for file events.

  • You do not care about maintaining some kinds of event tables. If you disable a consumer, the server does not spend time maintaining it. For example, if you do not care about aggregated event information, you can disable the summary table consumers to improve performance.

Example pre-filtering operations:

Disable all instruments:

mysql> UPDATE SETUP_INSTRUMENTS SET ENABLED = 'NO';

Now no events will be collected. This change, like other pre-filtering operations, affects other users as well, even if they want to see event information.

Disable all file instruments, adding them to the current set of disabled instruments:

mysql> UPDATE SETUP_INSTRUMENTS SET ENABLED = 'NO'
    -> WHERE NAME LIKE 'wait/io/file/%';

Disable only file instruments, enable all other instruments:

mysql> UPDATE SETUP_INSTRUMENTS
    -> SET ENABLED = IF(NAME LIKE 'wait/io/file/%', 'NO', 'YES');

The preceding queries use the LIKE operator and the pattern 'wait/io/file/%' to match all instrument names that begin with 'wait/io/file/. Additional information about specifying patterns to select instruments is given later in this section.

Enable all but those instruments in the mysys library:

mysql> UPDATE SETUP_INSTRUMENTS
    -> SET ENABLED = CASE WHEN NAME LIKE '%/mysys/%' THEN 'YES' ELSE 'NO' END;

Disable a specific instrument:

mysql> UPDATE SETUP_INSTRUMENTS SET ENABLED = 'NO'
    -> WHERE NAME = 'wait/synch/mutex/mysys/TMPDIR_mutex';

To toggle the state of an instrument, “flip” its ENABLED value:

mysql> UPDATE SETUP_INSTRUMENTS
    -> SET ENABLED = IF(ENABLED = 'YES', 'NO', 'YES')
    -> WHERE NAME = 'wait/synch/mutex/mysys/TMPDIR_mutex';

Changing which instruments are enabled does not flush the history tables. Events already collected remain in the current-events, history, and summary tables until displaced by newer events. If you disable instruments, you might need to wait a while before events for them are displaced by newer events of interest. Alternatively, use TRUNCATE TABLE to empty the history tables. You might want to truncate the summary tables as well to discard aggregate information for previously collected events.

Disable timing for all events:

mysql> UPDATE SETUP_INSTRUMENTS SET TIMED = 'NO';

Setting the TIMED column for instruments to NO affects Performance Schema table contents as described in Section 20.4, “Performance Schema Event Timing”.

If you disable a consumer, the server does not spend time maintaining it. For example, you can disable the summary table consumers if you do not care about aggregated event information:

mysql> UPDATE SETUP_CONSUMERS
    -> SET ENABLED = 'NO' WHERE NAME LIKE '%summary%';

Pre-filtering limits which event information is collected and is independent of any particular user. By contrast, post-filtering is performed by individual users and is performed by use of appropriate WHERE clauses that restrict what event information to select from the information available after pre-filtering has been applied.

Reasons to use post-filtering include the following:

  • To avoid making decisions for individual users about which event information is of interest.

  • To use Performance Schema to investigate a performance issue when the restrictions to impose via pre-filtering to use are not known in advance.

An example earlier in this section showed how to pre-filter for file instruments. If the event tables contain both file and nonfile information, post-filtering is another way to see information only for file events. Add a WHERE clause to queries to restrict event selection appropriately:

mysql> SELECT THREAD_ID, NUMBER_OF_BYTES
    -> FROM EVENTS_WAITS_HISTORY
    -> WHERE EVENT_NAME LIKE 'wait/io/file/%'
    -> AND NUMBER_OF_BYTES IS NOT NULL;
+-----------+-----------------+
| THREAD_ID | NUMBER_OF_BYTES |
+-----------+-----------------+
|        11 |              66 |
|        11 |              47 |
|        11 |             139 |
|         5 |              24 |
|         5 |             834 |
+-----------+-----------------+

Names given for filtering operations can be as specific or general as required. To indicate a single instrument or consumer, specify its name in full:

mysql> UPDATE SETUP_INSTRUMENTS
    -> SET ENABLED = 'NO'
    -> WHERE NAME = 'wait/synch/mutex/myisammrg/MYRG_INFO::mutex';

mysql> UPDATE SETUP_CONSUMERS
    -> SET ENABLED = 'NO' WHERE NAME = 'file_summary_by_instance';

To specify a group of instruments or consumers, use a pattern that matches the group members:

mysql> UPDATE SETUP_INSTRUMENTS
    -> SET ENABLED = 'NO'
    -> WHERE NAME LIKE 'wait/synch/mutex/%';

mysql> UPDATE SETUP_CONSUMERS
    -> SET ENABLED = 'NO' WHERE NAME LIKE '%summary%';

If you use a pattern, it should be chosen so that it matches all the items of interest and no others. For example, to select all file I/O instruments, it is better to use a pattern that includes the entire instrument name prefix:

... WHERE NAME LIKE 'wait/io/file/%';

If you use a pattern of '%/file/%', it will match other instruments that have a component of '/file/' anywhere in the name. Even less suitable is the pattern '%file%' because it will match instruments with 'file' anywhere in the name, such as wait/synch/mutex/sql/LOCK_des_key_file.

To check which instrument or consumer names a pattern matches, perform a simple test:

mysql> SELECT NAME FROM SETUP_INSTRUMENTS WHERE NAME LIKE 'pattern';

mysql> SELECT NAME FROM SETUP_CONSUMERS WHERE NAME LIKE 'pattern';

20.3. Performance Schema Status Monitoring

There are several status variables associated with Performance Schema:

mysql> SHOW STATUS LIKE 'perf%';
+------------------------------------------+-------+
| Variable_name                            | Value |
+------------------------------------------+-------+
| Performance_schema_cond_classes_lost     | 0     |
| Performance_schema_cond_instances_lost   | 0     |
| Performance_schema_file_classes_lost     | 0     |
| Performance_schema_file_handles_lost     | 0     |
| Performance_schema_file_instances_lost   | 0     |
| Performance_schema_locker_lost           | 0     |
| Performance_schema_mutex_classes_lost    | 0     |
| Performance_schema_mutex_instances_lost  | 0     |
| Performance_schema_rwlock_classes_lost   | 0     |
| Performance_schema_rwlock_instances_lost | 0     |
| Performance_schema_table_handles_lost    | 0     |
| Performance_schema_table_instances_lost  | 0     |
| Performance_schema_thread_classes_lost   | 0     |
| Performance_schema_thread_instances_lost | 0     |
+------------------------------------------+-------+

The Performance Schema status variables provide information about instrumentation that could not be loaded or created due to memory constraints. Names for these variables have several forms:

  • Performance_schema_xxx_classes_lost indicates how many instruments of type xxx could not be loaded.

  • Performance_schema_xxx_instances_lost indicates how many instances of object type xxx could not be created.

  • Performance_schema_xxx_handles_lost indicates how many instances of object type xxx could not be opened.

  • Performance_schema_locker_lost indicates how many events are “lost” or not recorded.

For example, if a mutex is instrumented in the server source but the server cannot allocate memory for the instrumentation at runtime, it increments Performance_schema_mutex_classes_lost. The mutex still functions as a synchronization object (that is, the server continues to function normally), but performance data for it will not be collected. If the instrument can be allocated, it can be used for initializing instrumented mutex instances. For a singleton mutex such as a global mutex, there will be only one instance. Other mutexes have an instance per connection, or per page in various caches and data buffers, so the number of instances varies over time. Increasing the maximum number of connections or the maximum size of some buffers will increase the maximum number of instances that might be allocated at once. If the server cannot create a given instrumented mutex instance, it increments Performance_schema_mutex_instances_lost.

Suppose that the following conditions hold:

  • The server was started with the --performance_schema_max_mutex_classes=200 option and thus has room for 200 mutex instruments.

  • 150 mutex instruments have been loaded already.

  • The plugin named plugin_a contains 40 mutex instruments.

  • The plugin named plugin_b contains 20 mutex instruments.

The server allocates mutex instruments for the plugins depending on how many they need and how many are available, as illustrated by the following sequence of statements:

INSTALL PLUGIN plugin_a

The server now has 150+40 = 190 mutex instruments.

UNINSTALL PLUGIN plugin_a;

The server still has 190 instruments. All the historical data generated by the plugin code is still available, but new events for the instruments are not collected.

INSTALL PLUGIN plugin_a;

The server detects that the 40 instruments are already defined, so no new instruments are created, and previously assigned internal memory buffers are reused. The server still has 190 instruments.

INSTALL PLUGIN plugin_b;

The server has room for 200-190 = 10 instruments (in this case, mutex classes), and sees that the plugin contains 20 new instruments. 10 instruments are loaded, and 10 are discarded or “lost.” The Performance_schema_mutex_classes_lost indicates the number of instruments (mutex classes) lost:

mysql> SHOW STATUS LIKE "perf%mutex_classes_lost";
+---------------------------------------+-------+
| Variable_name                         | Value |
+---------------------------------------+-------+
| Performance_schema_mutex_classes_lost | 10    |
+---------------------------------------+-------+
1 row in set (0.10 sec)

The instrumentation still works and collects (partial) data for plugin_b.

When the server cannot create a mutex instrument, these results occur:

The pattern just described applies to all types of instruments, not just mutexes.

A value of Performance_schema_mutex_classes_lost greater than 0 can happen in two cases:

  • To save a few bytes of memory, you start the server with --performance_schema_max_mutex_classes=N, where N is less than the default value. The default value is chosen to be sufficient to load all the plugins provided in the MySQL distribution, but this can be reduced if some plugins are never loaded. For example, you might choose not to load some of the storage engines in the distribution.

  • You load a third-party plugin that is instrumented for Performance Schema but do not allow for the plugin's instrumentation memory requirements when you start the server. Because it comes from a third party, the instrument memory consumption of this engine is not accounted for in the default value chosen for performance_schema_max_mutex_classes.

    If the server has insufficient resources for the plugin's instruments and you do not explicitly allocate more using --performance_schema_max_mutex_classes=N, loading the plugin leads to starvation of instruments.

If the value chosen for performance_schema_max_mutex_classes is too small, no error is reported in the error log and there is no failure at runtime. However, the content of the tables in the performance_schema database will miss events. The Performance_schema_mutex_classes_lost status variable is the only visible sign to indicate that some events were dropped internally due to failure to create instruments.

If an instrument is not lost, it is known to the Performance Schema, and is used when instrumenting instances. For example, wait/synch/mutex/sql/LOCK_delete is the name of a mutex instrument in the SETUP_INSTRUMENTS table. This single instrument is used when creating in the code (in THD::LOCK_delete) however many instances of the mutex are needed as the server runs. In this case, LOCK_delete is a mutex that is per connection (THD), so if a server has 1000 connections, there are 1000 threads, and 1000 instrumented LOCK_delete mutex instances (THD::LOCK_delete).

If the server does not have room for all these 1000 instrumented mutexes (instances), some mutexes are created with instrumentation, and some are created without instrumentation. If the server can create only 800 instances, 200 instances are lost. The server continues to run, but increments Performance_schema_mutex_instances_lost by 200 to indicate that instances could not be created.

A value of Performance_schema_mutex_instances_lost greater than 0 can happen when the code initializes more mutexes at runtime than were allocated for --performance_schema_max_mutex_instances=N.

The bottom line is that if SHOW STATUS LIKE 'perf%' says that nothing was lost (all values are zero), the Performance Schema data is accurate and can be relied upon. If something was lost, the data is incomplete, and the Performance Schema could not record everything given the insufficient amount of memory it was given to use. In this case, the specific Performance_schema_xxx_lost variable indicates the problem area.

It might be appropriate in some cases to cause deliberate instrument starvation. For example, if you do not care about performance data for file I/O, you can start the server with all Performance Schema parameters related to file I/O set to 0. No memory will be allocated for file-related classes, instances, or handles, and all file events will be lost.

To inspect the internal operation of the Performance Schema code, use SHOW ENGINE PERFORMANCE_SCHEMA STATUS:

mysql> SHOW ENGINE PERFORMANCE_SCHEMA STATUS\G
...
*************************** 3. row ***************************
  Type: performance_schema
  Name: EVENTS_WAITS_HISTORY.ROW_SIZE
Status: 76
*************************** 4. row ***************************
  Type: performance_schema
  Name: EVENTS_WAITS_HISTORY.ROW_COUNT
Status: 10000
*************************** 5. row ***************************
  Type: performance_schema
  Name: EVENTS_WAITS_HISTORY.MEMORY
Status: 760000
...
*************************** 57. row ***************************
  Type: performance_schema
  Name: PERFORMANCE_SCHEMA.MEMORY
Status: 26459600
...

The intent of this statement is to help the DBA to understand the effects that different options have on memory requirements.

Name values consist of two parts, which name an internal buffer and an attribute of the buffer, respectively:

  • Internal buffers that are exposed as a table in the performance_schema are named after the table. Examples: EVENTS_WAITS_HISTORY.ROW_SIZE, MUTEX_INSTANCES.ROW_COUNT.

  • Internal buffers that are not exposed as a table are named within parentheses. Examples: (PFS_COND_CLASS).ROW_SIZE, (PFS_MUTEX_CLASS).MEMORY.

  • Values that apply to Performance Schema as a whole begin with PERFORMANCE_SCHEMA. Example: PERFORMANCE_SCHEMA.MEMORY.

Attributes have these meanings:

  • ROW_SIZE cannot be changed. It is the size of the internal record used by the implementation.

  • ROW_COUNT can be changed depending on the configuration options.

  • For a table, tbl_name.MEMORY is the product of ROW_SIZE multiplied by ROW_COUNT. For Performance Schema as a whole, PERFORMANCE_SCHEMA.MEMORY is the sum of all the memory used (the sum of all other MEMORY values).

In some cases, there is a direct relationship between a configuration parameter and a SHOW ENGINE value. For example, EVENTS_WAITS_HISTORY_LONG.ROW_COUNT corresponds to performance_schema_events_waits_history_long_size. In other cases, the relationship is more complex. For example, EVENTS_WAITS_HISTORY.ROW_COUNT corresponds to performance_schema_events_waits_history_size (the number of rows per thread) multiplied by performance_schema_max_thread_instances ( the number of threads).

20.4. Performance Schema Event Timing

Events are collected by means of instrumentation added to the server source code. Instruments time events, which is how Performance Schema provides an idea of how long events take. It is also possible to configure instruments not to collect timing information. This section discusses the available timers and their characteristics, and how timing values are represented in events.

Timers vary in precision and the amount of overhead they involve. To see what timers are available and their characteristics, check the PERFORMANCE_TIMERS table:

mysql> SELECT * FROM PERFORMANCE_TIMERS;
+-------------+-----------------+------------------+----------------+
| TIMER_NAME  | TIMER_FREQUENCY | TIMER_RESOLUTION | TIMER_OVERHEAD |
+-------------+-----------------+------------------+----------------+
| CYCLE       |      2389029850 |                1 |             72 |
| NANOSECOND  |            NULL |             NULL |           NULL |
| MICROSECOND |         1000000 |                1 |            585 |
| MILLISECOND |            1035 |                1 |            738 |
| TICK        |             101 |                1 |            630 |
+-------------+-----------------+------------------+----------------+

The TIMER_NAME column shows the names of the available timers. CYCLE refers to the timer that is based on the CPU (processor) cycle counter. If the values associated with a given timer name are NULL, that timer is not supported on your platform. The rows that do not have NULL indicate which timers you can use.

TIMER_FREQUENCY indicates the number of timer units per second. For a cycle timer, the frequency is generally related to the CPU speed. The value shown was obtained on a system with a 2.4GHz processor. The other timers are based on fixed fractions of seconds. For TICK, the frequency may vary by platform (for example, some use 100 ticks/second, others 1000 ticks/second).

TIMER_RESOLUTION indicates the number of timer units by which timer values increase at a time. If a timer has a resolution of 10, its value increases by 10 each time.

TIMER_OVERHEAD is the minimal number of cycles of overhead to obtain one timing with the given timer. The overhead per event is twice the value displayed because the timer is invoked at the beginning and end of the event.

To see which timer is in effect or to change the timer, access the SETUP_TIMERS table, which has a single row:

mysql> SELECT * FROM SETUP_TIMERS;
+------+------------+
| NAME | TIMER_NAME |
+------+------------+
| wait | CYCLE      |
+------+------------+

mysql> UPDATE SETUP_TIMERS SET TIMER_NAME = 'MICROSECOND';

mysql> SELECT * FROM SETUP_TIMERS;
+------+-------------+
| NAME | TIMER_NAME  |
+------+-------------+
| wait | MICROSECOND |
+------+-------------+

Performance Schema uses the best timer available by default, but you can select a different one. Generally the best timer is CYCLE, which uses the CPU cycle counter whenever possible to provide high precision and low overhead.

The precision offered by the cycle counter depends on processor speed. If the processor runs at 1 GHz (one billion cycles/second) or higher, the cycle counter delivers sub-nanosecond precision. Using the cycle counter is much cheaper than getting the actual time of day. For example, the standard gettimeofday() function can take hundreds of cycles, which is an unacceptable overhead if data gathering occurs thousands or millions of times per second.

Cycle counters also have disadvantages:

  • End users expect to see timings in wall-clock units, such as fractions of a second. Converting from cycles to fractions of seconds can be expensive. For this reason, the conversion is a quick and fairly rough multiplication operation.

  • Processor cycle rate might change, such as when a laptop goes into power-saving mode or when a CPU slows down to reduce heat generation. If a processor's cycle rate fluctuates, conversion from cycles to real-time units is subject to error.

  • Cycle counters might be unreliable or unavailable depending on the processor or the operating system. For example, on Pentiums, the instruction is RDTSC (an assembly-language rather than a C instruction) and it is theoretically possible for the operating system to prevent user-mode programs from using it.

  • Some processor details related to out-of-order execution or multiprocessor synchronization might cause the counter to seem fast or slow by up to 1000 cycles.

Currently, MySQL works with cycle counters on x386 (Windows, Mac OS X, Linux, and Solaris and other Unix flavors), PowerPC, and IA-64.

Within events, times are stored in picoseconds (trillionths of a second) so that they all use a standard unit, regardless of which timer is selected. The timer used for an event is the one in effect when the event is timed. This timer is used to convert start and end values to picoseconds for storage in the event. If a different timer is selected, that affects only events that start afterward, not those already in progress.

The timer baseline (“time zero”) occurs at Performance Schema initialization during server startup. TIMER_START and TIMER_END values in events represent picoseconds since the baseline. TIMER_WAIT values are durations in picoseconds.

Picosecond values in events are approximate. Their accuracy is subject to the usual forms of error associated with conversion from one unit to another. If the CYCLE timer is used and the processor rate varies, there might be drift. For these reasons, it is not reasonable to look at the TIMER_START value for an event as an accurate measure of time elapsed since server startup. On the other hand, it is reasonable to use TIMER_START or TIMER_WAIT values in ORDER BY clauses to order events by start time or duration.

The choice of picoseconds in events rather than a value such as microseconds has a performance basis. One implementation goal was to show results in a uniform time unit, regardless of the timer. In an ideal world this time unit would look like a wall-clock unit and be reasonably precise; in other words, microseconds. But to convert cycles or nanoseconds to microseconds, it would be necessary to perform a division for every instrumentation. Division is expensive on many platforms. Multiplication is not expensive, so that is what is used. Therefore, the time unit is an integer multiple of the highest possible TIMER_FREQUENCY value, using a multiplier large enough to ensure that there is no major precision loss. The result is that the time unit is “picoseconds.” This precision is spurious, but the decision enables overhead to be minimized. If this decision turns out to be impractical in some way, we will revisit it.

The SETUP_INSTRUMENTS table has an ENABLED column to indicate the instruments for which to collect events. The table also has a TIMED column to indicate which instruments are timed. If an instrument is not enabled, it produces no events. If an enabled instrument is not timed, events produced by the instrument have NULL for the TIMER_START, TIMER_END, and TIMER_WAIT timer values. This in turn causes those values to be ignored when calculating the sum, minimum, maximum, and average time values in summary tables.

20.5. Performance Schema Event Instrument Naming Conventions

An instrument name consists of a sequence of components separated by '/' characters. Example names:

wait/io/file/myisam/log
wait/io/file/mysys/charset
wait/synch/cond/mysys/COND_alarm
wait/synch/cond/sql/BINLOG::update_cond
wait/synch/mutex/mysys/BITMAP_mutex
wait/synch/mutex/sql/Event_scheduler::LOCK_scheduler_state
wait/synch/mutex/sql/LOCK_delete
wait/synch/rwlock/myisam/MYISAM_SHARE::key_root_lock
wait/synch/rwlock/sql/Query_cache_query::lock

The instrument name space has a tree-like structure. The components of an instrument name from left to right provide a progression from more general to more specific. The number of components a name has depends on the type of instrument.

The interpretation of a given component in a name depends on the components to the left of it. For example, myisam appears in both of the following names, but myisam in the first name is related to file I/O, whereas in the second it is related to a synchronization instrument:

wait/io/file/myisam/log
wait/synch/cond/myisam/MI_SORT_INFO::cond

Instrument names consist of a prefix with a structure defined by the Performance Schema implementation and a suffix defined by the developer implementing the instrument code. For the prefix part of instrument names, the top level indicates the type of instrument. Currently this is always wait, so the naming tree has this structure:

  • wait

    A wait instrument.

    • wait/io

      An instrumented I/O operation.

      • wait/io/file

        An instrumented file I/O operation. For files, the wait is the time waiting for the file operation to complete (for example, a call to fwrite()). Due to caching, the physical file I/O on the disk might not happen within this call.

    • wait/sync

      An instrumented synchronization object. For synchronization objects, the TIMER_WAIT time includes the amount of time blocked while attempting to acquire a lock on the object, if any.

      • wait/sync/cond

        A condition is used by one thread to signal to other threads that something they were waiting for has happened. If a single thread was waiting for a condition, it can wake up and proceed with its execution. If several threads were waiting, they can all wake up and compete for the resource for which they were waiting.

      • wait/sync/mutex

        A mutual exclusion object used to allow access to a resource (such as a section of executable code) while preventing other threads from accessing the resource.

      • wait/sync/rwlock

        A read/write lock object used to lock a specific variable for access while preventing its use by other threads. A shared read lock can be acquired simultaneously by multiple threads. An exclusive write lock can be acquired by only one thread at a time.

The suffix part of instrument names comes from the code for the instruments themselves. For example, following the first three levels just described, the next levels are:

  • A name for the major component (a server module such as myisam, mysys, or sql) or a plugin name.

  • The name of a variable in the code, in the form XXX (a global variable) or CCC:MMM (a member MMM in class CCC). Examples: COND_thread_cache, THR_LOCK_myisam, BINLOG::LOCK_index.

20.6. Performance Schema Table General Characteristics

The database name performance_schema is lowercase. The names of tables in the database are uppercase. Normal case sensitivity rules apply, so on systems with case-sensitive file names, the database name and table names must be specified in the lettercase just indicated. This behavior can be modified by setting the lower_case_table_names system variable.

Most tables in the performance_schema database are read only and cannot be modified. Some of the setup tables have columns that can be modified to affect Performance Schema operation. Truncation is allowed to clear collected events or aggregation counters, so TRUNCATE TABLE can be used on tables containing those kinds of information, such as tables named with a prefix of EVENTS_WAITS.

Privileges are as for other databases and tables:

  • To retrieve from performance_schema tables, you must have the SELECT privilege.

  • To change those columns that can be modified, you must have the UPDATE privilege.

  • To truncate tables that can be truncated, you must have the DROP privilege.

20.7. Performance Schema Table Descriptions

Tables in the performance_schema database can be grouped as follows:

  • Setup tables. These tables are used to configure and display monitoring characteristics.

  • Current events table. The EVENTS_WAITS_CURRENT table contains the most recent event for each thread.

  • History tables. These tables have the same structure as EVENTS_WAITS_CURRENT but contain more rows. The EVENTS_WAITS_HISTORY table contains the most recent 10 events per thread. EVENTS_WAITS_HISTORY_LONG contains the most recent 10,000 events.

    To change the sizes of these tables, set the performance_schema_events_waits_history_size and performance_schema_events_waits_history_long_size system variables at server startup.

  • Summary tables. These tables contain information aggregated over all events, including those that have been discarded from the history tables.

  • Instance tables. These tables document what types of objects are instrumented. An instrumented object, when used by the server, produces an event. These tables provide event names and explanatory notes or status information.

  • Miscellaneous tables. These do not fall into any of the other table groups.

20.7.1. Performance Schema Setup Tables

The setup tables provide information about the current instrumentation and enable the monitoring configuration to be changed. For this reason, some columns in these tables can be changed if you have the UPDATE privilege.

The use of tables rather than individual variables for setup information provides a high degree of flexibility in modifying Performance Schema configuration. For example, you can use a single statement with standard SQL syntax to make multiple simultaneous configuration changes.

This group contains tables with names that match the pattern 'SETUP%':

mysql> SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES
    -> WHERE TABLE_SCHEMA = 'performance_schema'
    -> AND TABLE_NAME LIKE 'SETUP%';
+-------------------+
| TABLE_NAME        |
+-------------------+
| SETUP_CONSUMERS   |
| SETUP_INSTRUMENTS |
| SETUP_OBJECTS     |
| SETUP_TIMERS      |
+-------------------+

The SETUP_CONSUMERS table lists destination tables for event information:

mysql> SELECT * FROM SETUP_CONSUMERS;
+----------------------------------------------+---------+
| NAME                                         | ENABLED |
+----------------------------------------------+---------+
| events_waits_current                         | YES     |
| events_waits_history                         | YES     |
| events_waits_history_long                    | YES     |
| events_waits_summary_by_thread_by_event_name | YES     |
| events_waits_summary_by_event_name           | YES     |
| events_waits_summary_by_instance             | YES     |
| file_summary_by_event_name                   | YES     |
| file_summary_by_instance                     | YES     |
+----------------------------------------------+---------+

The SETUP_CONSUMERS table has these columns:

  • NAME

    The consumer name. This is the name of a table in the performance_schema database.

  • ENABLED

    Whether the consumer is enabled. This column can be modified. If you disable a consumer, the server does not spend time adding event information to it.

Disabling the events_waits_current consumer disables everything else that depends on waits, such as the EVENTS_WAITS_HISTORY and EVENTS_WAITS_HISTORY_LONG tables, and all summary tables.

The SETUP_INSTRUMENTS table lists classes of instrumented objects for which events can be collected:

mysql> SELECT * FROM SETUP_INSTRUMENTS;
+------------------------------------------------------------+---------+-------+
| NAME                                                       | ENABLED | TIMED |
+------------------------------------------------------------+---------+-------+
| wait/synch/mutex/sql/PAGE::lock                            | YES     | YES   |
| wait/synch/mutex/sql/TC_LOG_MMAP::LOCK_sync                | YES     | YES   |
| wait/synch/mutex/sql/TC_LOG_MMAP::LOCK_active              | YES     | YES   |
| wait/synch/mutex/sql/TC_LOG_MMAP::LOCK_pool                | YES     | YES   |
| wait/synch/mutex/sql/LOCK_des_key_file                     | YES     | YES   |
| wait/synch/mutex/sql/MYSQL_BIN_LOG::LOCK_index             | YES     | YES   |
...

Each instrument added to the source code provides a row for this table, even when the instrumented code is not executed. When an instrument is enabled and executed, instrumented instances are created, which are visible in the *_INSTANCES tables.

The SETUP_INSTRUMENTS table has these columns:

  • NAME

    The instrument name. Instrument names have multiple parts and form a hierarchy, as discussed in Section 20.5, “Performance Schema Event Instrument Naming Conventions”. Events produced from execution of an instrument have an EVENT_NAME value that is taken from the instrument NAME value. (Events do not really have a “name,” but this provides a way to associate events with instruments.)

  • ENABLED

    Whether the instrument is enabled. This column can be modified. A disabled instrument produces no events.

  • TIMED

    Whether the instrument is timed. This column can be modified.

    If an enabled instrument is not timed, the instrument code is enabled, but the timer is not. Events produced by the instrument have NULL for the TIMER_START, TIMER_END, and TIMER_WAIT timer values. This in turn causes those values to be ignored when calculating the sum, minimum, maximum, and average time values in summary tables.

The SETUP_OBJECTS table is reserved for future use, and may change without notice.

The SETUP_TIMERS table shows the currently selected event timer:

mysql> SELECT * FROM SETUP_TIMERS;
+------+------------+
| NAME | TIMER_NAME |
+------+------------+
| wait | CYCLE      |
+------+------------+

The SETUP_TIMERS.TIMER_NAME value can be changed to select a different timer. The value can be any of the PERFORMANCE_TIMERS.TIMER_NAME values. For an explanation of how event timing occurs, see Section 20.4, “Performance Schema Event Timing”.

The SETUP_TIMERS table has these columns:

  • NAME

    The type of instrument the timer is used for.

  • TIMER_NAME

    The timer that applies to the instrument type.

20.7.2. Performance Schema Current-Events Table

There is a single table for current events. Its name matches the pattern '%CURRENT':

mysql> SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES
    -> WHERE TABLE_SCHEMA = 'performance_schema'
    -> AND TABLE_NAME LIKE '%CURRENT';
+----------------------+
| TABLE_NAME           |
+----------------------+
| EVENTS_WAITS_CURRENT |
+----------------------+

The EVENTS_WAITS_CURRENT table contains a row per thread showing the current status of each thread's most recent monitored event. When nested events are implemented, it will be possible for a thread to have multiple events in progress simultaneously.

This table can be truncated with TRUNCATE TABLE.

Of the tables that contain event rows, EVENTS_WAITS_CURRENT is the most fundamental. Other tables that contain event rows are logically derived from the current events. For example, the history tables are collections of the most recent events, up to a fixed number of rows.

The EVENTS_WAITS_CURRENT table has these columns:

  • THREAD_ID, EVENT_ID

    The thread associated with the event and the event number. These two values taken together form a primary key that uniquely identifies the row. No two rows will have the same pair of values.

  • EVENT_NAME

    The name of the instrument from which the event was collected. This is a SETUP_INSTRUMENTS.NAME value. Instrument names have multiple parts and form a hierarchy, as discussed in Section 20.5, “Performance Schema Event Instrument Naming Conventions”.

  • SOURCE

    The name of the source file containing the instrumented code that produced the event and the line number in the file at which the instrumentation occurs.

  • TIMER_START, TIMER_END, TIMER_WAIT

    Timing information for the event. The unit for these values is picoseconds (trillionths of a second). The TIMER_START and TIMER_END values indicate when event timing started and ended. TIMER_WAIT is the event elapsed time (duration).

    If an event has not finished, TIMER_END and TIMER_WAIT are NULL.

    If an event is produced from an instrument that has TIMED = NO, timing information is not collected, and TIMER_START, TIMER_END, and TIMER_WAIT are all NULL.

    For discussion of picoseconds as the unit for event times and factors that affect time values, see Section 20.4, “Performance Schema Event Timing”.

  • SPINS

    For a mutex, the number of spin rounds. If the value is NULL, the code does not use spin rounds or spinning is not instrumented.

  • OBJECT_SCHEMA, OBJECT_NAME, OBJECT_TYPE, OBJECT_INSTANCE_BEGIN

    These columns identify the object “being acted on.” What that means depends on the object type.

    For a synchronization object (cond, mutex, rwlock):

    • OBJECT_SCHEMA, OBJECT_NAME, and OBJECT_TYPE are NULL.

    • OBJECT_INSTANCE_BEGIN is the address of the synchronization object in memory.

    For a file I/O object:

    • OBJECT_SCHEMA is NULL.

    • OBJECT_NAME is the file name.

    • OBJECT_TYPE is FILE.

    • OBJECT_INSTANCE_BEGIN is an address in memory.

    An OBJECT_INSTANCE_BEGIN value itself has no meaning, except that different values indicate different objects. OBJECT_INSTANCE_BEGIN can be used for debugging. For example, it can be used with GROUP BY OBJECT_INSTANCE_BEGIN to see whether the load on 1,000 mutexes (that protect, say, 1,000 pages or blocks of data) is spread evenly or just hitting a few bottlenecks. This can help you correlate with other sources of information if you see the same object address in a log file or another debugging or performance tool.

  • NESTING_EVENT_ID

    Currently NULL. Nested events are not implemented.

  • OPERATION

    The type of operation performed, such as lock, read, or write.

  • NUMBER_OF_BYTES

    The number of bytes read or written by the operation.

20.7.3. Performance Schema History Tables

This group contains tables with names that match the pattern '%HISTORY' or '%HISTORY_LONG':

mysql> SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES
    -> WHERE TABLE_SCHEMA = 'performance_schema'
    -> AND (TABLE_NAME LIKE '%HISTORY' OR TABLE_NAME LIKE '%HISTORY_LONG');
+---------------------------+
| TABLE_NAME                |
+---------------------------+
| EVENTS_WAITS_HISTORY      |
| EVENTS_WAITS_HISTORY_LONG |
+---------------------------+

The history tables, EVENTS_WAITS_HISTORY and EVENTS_WAITS_HISTORY_LONG, contain the most recent 10 events per thread and most recent 10,000 events, respectively. As new events are added to a history table, older events are discarded if the table is full. Events are not added to the history tables until they have ended.

Event history tables can be truncated with TRUNCATE TABLE.

The history tables have the same structure as EVENTS_WAITS_CURRENT. See Section 20.7.2, “Performance Schema Current-Events Table”.

20.7.4. Performance Schema Summary Tables

Summary tables provide aggregate information for terminated events over time. The tables in this group summarize event data in different ways.

This group contains tables with names that match the pattern '%SUMMARY%':

mysql> SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES
    -> WHERE TABLE_SCHEMA = 'performance_schema'
    -> AND TABLE_NAME LIKE '%SUMMARY%';
+----------------------------------------------+
| TABLE_NAME                                   |
+----------------------------------------------+
| EVENTS_WAITS_SUMMARY_BY_EVENT_NAME           |
| EVENTS_WAITS_SUMMARY_BY_INSTANCE             |
| EVENTS_WAITS_SUMMARY_BY_THREAD_BY_EVENT_NAME |
| FILE_SUMMARY_BY_EVENT_NAME                   |
| FILE_SUMMARY_BY_INSTANCE                     |
+----------------------------------------------+

Each summary table contains columns to hold aggregated information, and columns that show the groupings for which the aggregated values were computed. Tables that summarize events in similar ways have similar sets of columns, differing only in the columns that show what the groupings are.

Summary tables can be truncated with TRUNCATE TABLE.

EVENTS_WAITS_SUMMARY_BY_xxx tables have these columns in common:

  • COUNT_STAR

    The number of summarized events. This value includes all events, whether timed or not.

  • SUM_TIMER_WAIT

    The total wait time of the summarized timed events. This value is calculated only for timed events because nontimed events have a wait time of NULL. The same is true for the other xxx_TIMER_WAIT values.

  • MIN_TIMER_WAIT

    The minimum wait time of the summarized timed events.

  • AVG_TIMER_WAIT

    The average wait time of the summarized timed events.

  • MAX_TIMER_WAIT

    The maximum wait time of the summarized timed events.

The remaining columns in the EVENTS_WAITS_SUMMARY_BY_xxx tables indicate how events were aggregated:

  • EVENTS_WAITS_SUMMARY_BY_EVENT_NAME has an EVENT_NAME column. Each row summarizes events for a given instrument. An instrument might be used to create multiple instances of the instrumented object. For example, if there is an instrument for a mutex that is created for each connection, there are as many instances as there are connections. The summary row for the instrument summarizes over all these instances.

  • EVENTS_WAITS_SUMMARY_BY_INSTANCE has EVENT_NAME and OBJECT_INSTANCE_BEGIN columns. Each row summarizes events for a given instrument instance. If an instrument is used to create multiple instances, each instance has a unique OBJECT_INSTANCE_BEGIN value, so these instances are summarized separately in this table.

  • EVENTS_WAITS_SUMMARY_BY_THREAD_BY_EVENT_NAME has THREAD_ID and EVENT_NAME columns. Each row summarizes events for a given thread and instrument.

FILE_SUMMARY_BY_xxx tables have these columns in common:

  • COUNT_READ

    The number of read operations in the summarized events.

  • COUNT_WRITE

    The number of write operations in the summarized events.

  • SUM_NUMBER_OF_BYTES_READ

    The number of bytes read in the summarized events.

  • SUM_NUMBER_OF_BYTES_WRITE

    The number of bytes written in the summarized events.

The remaining columns in the FILE_SUMMARY_BY_xxx tables indicate how events were aggregated:

  • FILE_SUMMARY_BY_EVENT_NAME has an EVENT_NAME column. Each row summarizes events for a given instrument.

  • FILE_SUMMARY_BY_INSTANCE has FILE_NAME and EVENT_NAME columns. Each row summarizes events for a given file.

Example:

mysql> SELECT * FROM EVENTS_WAITS_SUMMARY_BY_EVENT_NAME\G
...
*************************** 6. row ***************************
    EVENT_NAME: wait/synch/mutex/sql/MYSQL_BIN_LOG::LOCK_index
    COUNT_STAR: 8
SUM_TIMER_WAIT: 2119302
MIN_TIMER_WAIT: 196092
AVG_TIMER_WAIT: 264912
MAX_TIMER_WAIT: 569421
...
*************************** 9. row ***************************
    EVENT_NAME: wait/synch/mutex/sql/hash_filo::lock
    COUNT_STAR: 69
SUM_TIMER_WAIT: 16848828
MIN_TIMER_WAIT: 0
AVG_TIMER_WAIT: 244185
MAX_TIMER_WAIT: 735345
...

20.7.5. Performance Schema Instance Tables

Instance tables document what types of objects are instrumented. They provide event names and explanatory notes or status information.

This group contains tables with names that match the pattern '%INSTANCES' (plural). It does not include tables with '_BY_INSTANCE' in their name; those are summary tables, not instance tables.

mysql> SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES
    -> WHERE TABLE_SCHEMA = 'performance_schema'
    -> AND TABLE_NAME LIKE '%INSTANCES';
+------------------+
| TABLE_NAME       |
+------------------+
| COND_INSTANCES   |
| FILE_INSTANCES   |
| MUTEX_INSTANCES  |
| RWLOCK_INSTANCES |
+------------------+

These tables list instrumented synchronization objects and files. Each table has an EVENT_NAME or NAME column to indicate the instrument associated with each row. Instrument names have multiple parts and form a hierarchy, as discussed in Section 20.5, “Performance Schema Event Instrument Naming Conventions”.

There are three types of synchronization objects: cond, mutex, and rwlock. These objects are described in Section 20.5, “Performance Schema Event Instrument Naming Conventions”.

The COND_INSTANCES table has these columns:

  • NAME

    The instrument name associated with the condition.

  • OBJECT_INSTANCE_BEGIN

    The address in memory of the condition that was instrumented.

The FILE_INSTANCES table lists all the files seen by the Performance Schema when executing file I/O instrumentation. If a file on disk has never been opened, it will not be in FILE_INSTANCES. When a file is deleted from the disk, it is also removed from the FILE_INSTANCES table.

The FILE_INSTANCES table has these columns:

  • FILE_NAME

    The file name.

  • EVENT_NAME

    The instrument name associated with the file.

  • OPEN_COUNT

    The count of open handles on the file. If a file was opened and then closed, it was opened 1 time, but OPEN_COUNT will be 0. To list all the files currently opened by the server, use WHERE OPEN_COUNT > 0.

The MUTEX_INSTANCES table has these columns:

  • NAME

    The instrument name associated with the mutex.

  • OBJECT_INSTANCE_BEGIN

    The address in memory of the mutex that was instrumented.

  • LOCKED_BY_THREAD_ID

    When a thread currently has a mutex locked, LOCKED_BY_THREAD_ID is the THREAD_ID of the locking thread, otherwise it is NULL.

The RWLOCK_INSTANCES table has these columns:

  • NAME

    The instrument name associated with the lock.

  • OBJECT_INSTANCE_BEGIN

    The address in memory of the lock that was instrumented.

  • WRITE_LOCKED_BY_THREAD_ID

    When a thread currently has an rwlock locked in exclusive (write) mode, WRITE_LOCKED_BY_THREAD_ID is the THREAD_ID of the locking thread, otherwise it is NULL.

  • READ_LOCKED_BY_COUNT

    When a thread currently has an rwlock locked in shared (read) mode, READ_LOCKED_BY_COUNT is incremented by 1. This is a counter only, so it cannot be used directly to find which thread holds a read lock, but it can be used to see whether there is a read contention on an rwlock, and see how many readers are currently active.

The MUTEX_INSTANCES.LOCKED_BY_THREAD_ID and RWLOCK_INSTANCES.WRITE_LOCKED_BY_THREAD_ID columns are extremely important for investigating performance bottlenecks or deadlocks. For examples of how to use them for this purpose, see Section 20.11, “Using Performance Schema to Diagnose Problems”

20.7.6. Performance Schema Miscellaneous Tables

The PERFORMANCE_TIMERS table shows which event timers are available:

mysql> SELECT * FROM PERFORMANCE_TIMERS;
+-------------+-----------------+------------------+----------------+
| TIMER_NAME  | TIMER_FREQUENCY | TIMER_RESOLUTION | TIMER_OVERHEAD |
+-------------+-----------------+------------------+----------------+
| CYCLE       |      2389029850 |                1 |             72 |
| NANOSECOND  |            NULL |             NULL |           NULL |
| MICROSECOND |         1000000 |                1 |            585 |
| MILLISECOND |            1035 |                1 |            738 |
| TICK        |             101 |                1 |            630 |
+-------------+-----------------+------------------+----------------+

If the values associated with a given timer name are NULL, that timer is not supported on your platform. The rows that do not have NULL indicate which timers you can use.

The PERFORMANCE_TIMERS table has these columns:

  • TIMER_NAME

    The name by which to refer to the timer.

  • TIMER_FREQUENCY

    The number of timer units per second. For a cycle timer, the frequency is generally related to the CPU speed. The CYCLE value of 2388761194 was obtained on a system with a 2.4GHz processor.

  • TIMER_RESOLUTION

    Indicates the number of timer units by which timer values increase at a time. If a timer has a resolution of 10, its value increases by 10 each time.

  • TIMER_OVERHEAD

    The minimal number of cycles of overhead to obtain one timing with the given timer. Performance Schema determines this value by invoking the timer 20 times during initialization and picking the smallest value. The total overhead really is twice this because the instrumentation invokes the timer at the start and end of each event. The timer code is called only for timed events, so this overhead does not apply for nontimed events.

The PROCESSLIST table has these columns:

  • THREAD_ID

    This is the unique identifier of an instrumented thread.

  • ID

    For threads that are displayed in INFORMATION_SCHEMA.PROCESSLIST, this is the INFORMATION_SCHEMA.ID value. ID is not unique, and is 0 for threads not associated with a user connection, such as server internal background threads.

  • NAME

    NAME is the name associated with the instrumentation of the code in the server. For example, thread/sql/one_connection corresponds to the thread function in the code responsible for handling a user connection.

20.8. Performance Schema and Plugins

Removing the plugin with UNINSTALL PLUGIN does not affect information already collected for code in the plugin. Time spent executing the code while the plugin was loaded was still spent even if the plugin is unloaded later. The associated event information, including aggregate information, remains readable in performance_schema database tables. For additional information about the effect of plugin installation and removal, see Section 20.3, “Performance Schema Status Monitoring”.

A plugin implementor who instruments plugin code should document its instrumentation characteristics to enable those who load the plugin to account for its requirements. For example, a third-party storage engine should include in its documentation how much memory the engine needs for mutex and other instruments.

20.9. Performance Schema System Variables

Performance Schema implements several system variables that provide configuration information:

mysql> SHOW VARIABLES LIKE 'perf%';
+---------------------------------------------------+--------+
| Variable_name                                     | Value  |
+---------------------------------------------------+--------+
| performance_schema                                | ON     |
| performance_schema_events_waits_history_long_size | 250    |
| performance_schema_events_waits_history_size      | 10     |
| performance_schema_max_cond_classes               | 80     |
| performance_schema_max_cond_instances             | 1000   |
| performance_schema_max_file_classes               | 50     |
| performance_schema_max_file_handles               | 32768  |
| performance_schema_max_file_instances             | 10000  |
| performance_schema_max_mutex_classes              | 200    |
| performance_schema_max_mutex_instances            | 1000   |
| performance_schema_max_rwlock_classes             | 20     |
| performance_schema_max_rwlock_instances           | 1000   |
| performance_schema_max_table_handles              | 100000 |
| performance_schema_max_table_instances            | 50000  |
| performance_schema_max_thread_classes             | 50     |
| performance_schema_max_thread_instances           | 1000   |
+---------------------------------------------------+--------+

Table 20.1. Performance Schema Variable Reference

NameCmd-LineOption fileSystem VarStatus VarVar ScopeDynamic
performance_schemaYesYesYes GlobalNo
Performance_schema_cond_classes_lost   YesGlobalNo
Performance_schema_cond_instances_lost   YesGlobalNo
performance_schema_events_waits_history_long_sizeYesYesYes GlobalNo
performance_schema_events_waits_history_sizeYesYesYes GlobalNo
Performance_schema_file_classes_lost   YesGlobalNo
Performance_schema_file_handles_lost   YesGlobalNo
Performance_schema_file_instances_lost   YesGlobalNo
Performance_schema_locker_lost   YesGlobalNo
performance_schema_max_cond_classesYesYesYes GlobalNo
performance_schema_max_cond_instancesYesYesYes GlobalNo
performance_schema_max_file_classesYesYesYes GlobalNo
performance_schema_max_file_handlesYesYesYes GlobalNo
performance_schema_max_file_instancesYesYesYes GlobalNo
performance_schema_max_mutex_classesYesYesYes GlobalNo
performance_schema_max_mutex_instancesYesYesYes GlobalNo
performance_schema_max_rwlock_classesYesYesYes GlobalNo
performance_schema_max_rwlock_instancesYesYesYes GlobalNo
performance_schema_max_table_handlesYesYesYes GlobalNo
performance_schema_max_table_instancesYesYesYes GlobalNo
performance_schema_max_thread_classesYesYesYes GlobalNo
performance_schema_max_thread_instancesYesYesYes GlobalNo
Performance_schema_mutex_classes_lost   YesGlobalNo
Performance_schema_mutex_instances_lost   YesGlobalNo
Performance_schema_rwlock_classes_lost   YesGlobalNo
Performance_schema_rwlock_instances_lost   YesGlobalNo
Performance_schema_table_handles_lost   YesGlobalNo
Performance_schema_table_instances_lost   YesGlobalNo
Performance_schema_thread_classes_lost   YesGlobalNo
Performance_schema_thread_instances_lost   YesGlobalNo

The variables have the following meanings:

20.10. Performance Schema Status Variables

Performance Schema implements several status variables that provide information about instrumentation that could not be loaded or created due to memory constraints:

mysql> SHOW STATUS LIKE 'perf%';
+------------------------------------------+-------+
| Variable_name                            | Value |
+------------------------------------------+-------+
| Performance_schema_cond_classes_lost     | 0     |
| Performance_schema_cond_instances_lost   | 0     |
| Performance_schema_file_classes_lost     | 0     |
| Performance_schema_file_handles_lost     | 0     |
| Performance_schema_file_instances_lost   | 0     |
| Performance_schema_locker_lost           | 0     |
| Performance_schema_mutex_classes_lost    | 0     |
| Performance_schema_mutex_instances_lost  | 0     |
| Performance_schema_rwlock_classes_lost   | 0     |
| Performance_schema_rwlock_instances_lost | 0     |
| Performance_schema_table_handles_lost    | 0     |
| Performance_schema_table_instances_lost  | 0     |
| Performance_schema_thread_classes_lost   | 0     |
| Performance_schema_thread_instances_lost | 0     |
+------------------------------------------+-------+

Names for these variables have several forms:

  • Performance_schema_xxx_classes_lost

    How many instruments of type xxx could not be loaded.

  • Performance_schema_xxx_instances_lost

    How many instances of object type xxx could not be created.

  • Performance_schema_xxx_handles_lost

    How many instances of object type xxx could not be opened.

  • Performance_schema_locker_lost

    How many events are “lost” or not recorded, due to the following conditions:

    • Events are recursive (for example, waiting for A caused a wait on B, which caused a wait on C).

    • The depth of the nested events stack is greater than the limit imposed by the implementation.

    Currently, events recorded by Performance Schema are not recursive, so that this variable should always be 0.

For information on using these variables to check Performance Schema status, see Section 20.3, “Performance Schema Status Monitoring”.

20.11. Using Performance Schema to Diagnose Problems

The Performance Schema is a tool to help a DBA do performance tuning by taking real measurements instead of “wild guesses.” This section demonstrates some ways to use Performance Schema for this purpose. The discussion here relies on the use of event filtering, which is described in Section 20.2.3, “Event Collection Pre-Filtering and Post-Filtering”.

The following example provides one methodology that you can use to analyze a repeatable problem, such as investigating a performance bottleneck. To begin, you should have a repeatable use case where performance is deemed “too slow” and needs optimization, and you should enable all instrumentation (no pre-filtering at all).

  1. Run the use case.

  2. Using the Performance Schema tables, analyze the root cause of the performance problem. This analysis will rely heavily on post-filtering.

  3. For problem areas that are ruled out, disable the corresponding instruments. For example, if analysis shows that the issue is not related to file I/O in a particular storage engine, disable the file I/O instruments for that engine. Then truncate the history and summary tables to remove previously collected events.

  4. Repeat the process at step 1.

    At each iteration, the Performance Schema output, particularly the EVENTS_WAITS_HISTORY_LONG table, will contain less and less “noise” caused by nonsignificant instruments, and given that this table has a fixed size, will contain more and more data relevant to the analysis of the problem at hand.

    At each iteration, investigation should lead closer and closer to the root cause of the problem, as the “signal/noise” ratio will improve, making analysis easier.

  5. Once a root cause of performance bottleneck is identified, take the appropriate corrective action, such as:

    • Tune the server parameters (cache sizes, memory, and so forth).

    • Tune a query by writing it differently,

    • Tune the database schema (tables, indexes, and so forth).

    • Tune the code (this applies to storage engine or server developers only).

  6. Start again at step 1, to see the effects of the changes on performance.

The MUTEX_INSTANCES.LOCKED_BY_THREAD_ID and RWLOCK_INSTANCES.WRITE_LOCKED_BY_THREAD_ID columns are extremely important for investigating performance bottlenecks or deadlocks. This is made possible by Performance Schema instrumentation as follows:

  1. Suppose that thread 1 is stuck waiting for a mutex.

  2. You can determine what the thread is waiting for:

    SELECT * FROM EVENTS_WAITS_CURRENT WHERE THREAD_ID = thread_1;
    

    Say the query result identifies that the thread is waiting for mutex A, found in EVENTS_WAITS_CURRENT.OBJECT_INSTANCE_BEGIN.

  3. You can determine which thread is holding mutex A:

    SELECT * FROM MUTEX_INSTANCES WHERE OBJECT_INSTANCE_BEGIN = mutex_A;
    

    Say the query result identifies that it is thread 2 holding mutex A, as found in MUTEX_INSTANCES.LOCKED_BY_THREAD_ID.

  4. You can see what thread 2 is doing:

    SELECT * FROM EVENTS_WAITS_CURRENT WHERE THREAD_ID = thread_2;