Documentation Home
MySQL Performance Schema
Related Documentation Download this Excerpt
PDF (US Ltr) - 0.9Mb
PDF (A4) - 0.9Mb


MySQL Performance Schema  /  Performance Schema Table Descriptions  /  Performance Schema Stage Event Tables

10.5 Performance Schema Stage Event Tables

The Performance Schema instruments stages, which are steps during the statement-execution process, such as parsing a statement, opening a table, or performing a filesort operation. Stages correspond to the thread states displayed by SHOW PROCESSLIST or that are visible in the Information Schema PROCESSLIST table. Stages begin and end when state values change.

Within the event hierarchy, wait events nest within stage events, which nest within statement events, which nest within transaction events.

These tables store stage events:

The following sections describe the stage event tables. There are also summary tables that aggregate information about stage events; see Section 10.15.2, “Stage Summary Tables”.

For more information about the relationship between the three stage event tables, see Performance Schema Tables for Current and Historical Events.

Configuring Stage Event Collection

To control whether to collect stage events, set the state of the relevant instruments and consumers:

  • The setup_instruments table contains instruments with names that begin with stage. Use these instruments to enable or disable collection of individual stage event classes.

  • The setup_consumers table contains consumer values with names corresponding to the current and historical stage event table names. Use these consumers to filter collection of stage events.

Other than those instruments that provide statement progress information, the stage instruments are disabled by default. For example:

mysql> SELECT *
       FROM performance_schema.setup_instruments
       WHERE NAME RLIKE 'stage/sql/[a-c]';
+----------------------------------------------------+---------+-------+
| NAME                                               | ENABLED | TIMED |
+----------------------------------------------------+---------+-------+
| stage/sql/After create                             | NO      | NO    |
| stage/sql/allocating local table                   | NO      | NO    |
| stage/sql/altering table                           | NO      | NO    |
| stage/sql/committing alter table to storage engine | NO      | NO    |
| stage/sql/Changing master                          | NO      | NO    |
| stage/sql/Checking master version                  | NO      | NO    |
| stage/sql/checking permissions                     | NO      | NO    |
| stage/sql/checking privileges on cached query      | NO      | NO    |
| stage/sql/checking query cache for query           | NO      | NO    |
| stage/sql/cleaning up                              | NO      | NO    |
| stage/sql/closing tables                           | NO      | NO    |
| stage/sql/Connecting to master                     | NO      | NO    |
| stage/sql/converting HEAP to MyISAM                | NO      | NO    |
| stage/sql/Copying to group table                   | NO      | NO    |
| stage/sql/Copying to tmp table                     | NO      | NO    |
| stage/sql/copy to tmp table                        | NO      | NO    |
| stage/sql/Creating sort index                      | NO      | NO    |
| stage/sql/creating table                           | NO      | NO    |
| stage/sql/Creating tmp table                       | NO      | NO    |
+----------------------------------------------------+---------+-------+

Stage event instruments that provide statement progress information are enabled and timed by default:

mysql> SELECT *
       FROM performance_schema.setup_instruments
       WHERE ENABLED='YES' AND NAME LIKE "stage/%";
+------------------------------------------------------+---------+-------+
| NAME                                                 | ENABLED | TIMED |
+------------------------------------------------------+---------+-------+
| stage/sql/copy to tmp table                          | YES     | YES   |
| stage/innodb/alter table (end)                       | YES     | YES   |
| stage/innodb/alter table (flush)                     | YES     | YES   |
| stage/innodb/alter table (insert)                    | YES     | YES   |
| stage/innodb/alter table (log apply index)           | YES     | YES   |
| stage/innodb/alter table (log apply table)           | YES     | YES   |
| stage/innodb/alter table (merge sort)                | YES     | YES   |
| stage/innodb/alter table (read PK and internal sort) | YES     | YES   |
| stage/innodb/buffer pool load                        | YES     | YES   |
+------------------------------------------------------+---------+-------+

The stage consumers are disabled by default:

mysql> SELECT *
       FROM performance_schema.setup_consumers
       WHERE NAME LIKE 'events_stages%';
+----------------------------+---------+
| NAME                       | ENABLED |
+----------------------------+---------+
| events_stages_current      | NO      |
| events_stages_history      | NO      |
| events_stages_history_long | NO      |
+----------------------------+---------+

To control stage event collection at server startup, use lines like these in your my.cnf file:

  • Enable:

    [mysqld]
    performance-schema-instrument='stage/%=ON'
    performance-schema-consumer-events-stages-current=ON
    performance-schema-consumer-events-stages-history=ON
    performance-schema-consumer-events-stages-history-long=ON
  • Disable:

    [mysqld]
    performance-schema-instrument='stage/%=OFF'
    performance-schema-consumer-events-stages-current=OFF
    performance-schema-consumer-events-stages-history=OFF
    performance-schema-consumer-events-stages-history-long=OFF

To control stage event collection at runtime, update the setup_instruments and setup_consumers tables:

  • Enable:

    UPDATE performance_schema.setup_instruments
    SET ENABLED = 'YES', TIMED = 'YES'
    WHERE NAME LIKE 'stage/%';
    UPDATE performance_schema.setup_consumers
    SET ENABLED = 'YES'
    WHERE NAME LIKE 'events_stages%';
  • Disable:

    UPDATE performance_schema.setup_instruments
    SET ENABLED = 'NO', TIMED = 'NO'
    WHERE NAME LIKE 'stage/%';
    UPDATE performance_schema.setup_consumers
    SET ENABLED = 'NO'
    WHERE NAME LIKE 'events_stages%';

To collect only specific stage events, enable only the corresponding stage instruments. To collect stage events only for specific stage event tables, enable the stage instruments but only the stage consumers corresponding to the desired tables.

The setup_timers table contains a row with a NAME value of stage that indicates the unit for stage event timing. The default unit is NANOSECOND:

mysql> SELECT *
       FROM performance_schema.setup_timers
       WHERE NAME = 'stage';
+-------+------------+
| NAME  | TIMER_NAME |
+-------+------------+
| stage | NANOSECOND |
+-------+------------+

To change the timing unit, modify the TIMER_NAME value:

UPDATE performance_schema.setup_timers
SET TIMER_NAME = 'MICROSECOND'
WHERE NAME = 'stage';

For additional information about configuring event collection, see Chapter 4, Performance Schema Startup Configuration, and Chapter 5, Performance Schema Runtime Configuration.

Stage Event Progress Information

The Performance Schema stage event tables contain two columns that, taken together, provide a stage progress indicator for each row:

  • WORK_COMPLETED: The number of work units completed for the stage

  • WORK_ESTIMATED: The number of work units expected for the stage

Each column is NULL if no progress information is provided for an instrument. Interpretation of the information, if it is available, depends entirely on the instrument implementation. The Performance Schema tables provide a container to store progress data, but make no assumptions about the semantics of the metric itself:

  • A work unit is an integer metric that increases over time during execution, such as the number of bytes, rows, files, or tables processed. The definition of work unit for a particular instrument is left to the instrumentation code providing the data.

  • The WORK_COMPLETED value can increase one or many units at a time, depending on the instrumented code.

  • The WORK_ESTIMATED value can change during the stage, depending on the instrumented code.

Instrumentation for a stage event progress indicator can implement any of the following behaviors:

  • No progress instrumentation

    This is the most typical case, where no progress data is provided. The WORK_COMPLETED and WORK_ESTIMATED columns are both NULL.

  • Unbounded progress instrumentation

    Only the WORK_COMPLETED column is meaningful. No data is provided for the WORK_ESTIMATED column, which displays 0.

    By querying the events_stages_current table for the monitored session, a monitoring application can report how much work has been performed so far, but cannot report whether the stage is near completion. Currently, no stages are instrumented like this.

  • Bounded progress instrumentation

    The WORK_COMPLETED and WORK_ESTIMATED columns are both meaningful.

    This type of progress indicator is appropriate for an operation with a defined completion criterion, such as the table-copy instrument described later. By querying the events_stages_current table for the monitored session, a monitoring application can report how much work has been performed so far, and can report the overall completion percentage for the stage, by computing the WORK_COMPLETED / WORK_ESTIMATED ratio.

The stage/sql/copy to tmp table instrument illustrates how progress indicators work. During execution of an ALTER TABLE statement, the stage/sql/copy to tmp table stage is used, and this stage can execute potentially for a long time, depending on the size of the data to copy.

The table-copy task has a defined termination (all rows copied), and the stage/sql/copy to tmp table stage is instrumented to provided bounded progress information: The work unit used is number of rows copied, WORK_COMPLETED and WORK_ESTIMATED are both meaningful, and their ratio indicates task percentage complete.

To enable the instrument and the relevant consumers, execute these statements:

UPDATE performance_schema.setup_instruments
SET ENABLED='YES'
WHERE NAME='stage/sql/copy to tmp table';
UPDATE performance_schema.setup_consumers
SET ENABLED='YES'
WHERE NAME LIKE 'events_stages_%';

To see the progress of an ongoing ALTER TABLE statement, select from the events_stages_current table.