Documentation Home
MySQL 5.7 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 37.9Mb
PDF (A4) - 37.9Mb
PDF (RPM) - 36.5Mb
HTML Download (TGZ) - 9.9Mb
HTML Download (Zip) - 9.9Mb
HTML Download (RPM) - 8.7Mb
Man Pages (TGZ) - 209.4Kb
Man Pages (Zip) - 318.7Kb
Info (Gzip) - 3.5Mb
Info (Zip) - 3.5Mb
Excerpts from this Manual

13.7.5.36 SHOW TABLE STATUS Syntax

SHOW TABLE STATUS
    [{FROM | IN} db_name]
    [LIKE 'pattern' | WHERE expr]

SHOW TABLE STATUS works likes SHOW TABLES, but provides a lot of information about each non-TEMPORARY table. You can also get this list using the mysqlshow --status db_name command. The LIKE clause, if present, indicates which table names to match. The WHERE clause can be given to select rows using more general conditions, as discussed in Section 24.35, “Extensions to SHOW Statements”.

This statement also displays information about views.

SHOW TABLE STATUS output has these columns:

  • Name

    The name of the table.

  • Engine

    The storage engine for the table. See Chapter 14, The InnoDB Storage Engine, and Chapter 15, Alternative Storage Engines.

    For partitioned tables, Engine shows the name of the storage engine used by all partitions.

  • Version

    The version number of the table's .frm file.

  • Row_format

    The row-storage format (Fixed, Dynamic, Compressed, Redundant, Compact). For MyISAM tables, Dynamic corresponds to what myisamchk -dvv reports as Packed. InnoDB table format is either Redundant or Compact when using the Antelope file format, or Compressed or Dynamic when using the Barracuda file format.

  • Rows

    The number of rows. Some storage engines, such as MyISAM, store the exact count. For other storage engines, such as InnoDB, this value is an approximation, and may vary from the actual value by as much as 40% to 50%. In such cases, use SELECT COUNT(*) to obtain an accurate count.

    The Rows value is NULL for INFORMATION_SCHEMA tables.

    For InnoDB tables, the row count is only a rough estimate used in SQL optimization. (This is also true if the InnoDB table is partitioned.)

  • Avg_row_length

    The average row length.

    Refer to the notes at the end of this section for related information.

  • Data_length

    For MyISAM, Data_length is the length of the data file, in bytes.

    For InnoDB, Data_length is the approximate amount of memory allocated for the clustered index, in bytes. Specifically, it is the clustered index size, in pages, multiplied by the InnoDB page size.

    Refer to the notes at the end of this section for information regarding other storage engines.

  • Max_data_length

    For MyISAM, Max_data_length is maximum length of the data file. This is the total number of bytes of data that can be stored in the table, given the data pointer size used.

    Unused for InnoDB.

    Refer to the notes at the end of this section for information regarding other storage engines.

  • Index_length

    For MyISAM, Index_length is the length of the index file, in bytes.

    For InnoDB, Index_length is the approximate amount of memory allocated for non-clustered indexes, in bytes. Specifically, it is the sum of non-clustered index sizes, in pages, multiplied by the InnoDB page size.

    Refer to the notes at the end of this section for information regarding other storage engines.

  • Data_free

    The number of allocated but unused bytes.

    InnoDB tables report the free space of the tablespace to which the table belongs. For a table located in the shared tablespace, this is the free space of the shared tablespace. If you are using multiple tablespaces and the table has its own tablespace, the free space is for only that table. Free space means the number of bytes in completely free extents minus a safety margin. Even if free space displays as 0, it may be possible to insert rows as long as new extents need not be allocated.

    For NDB Cluster, Data_free shows the space allocated on disk for, but not used by, a Disk Data table or fragment on disk. (In-memory data resource usage is reported by the Data_length column.)

    For partitioned tables, this value is only an estimate and may not be absolutely correct. A more accurate method of obtaining this information in such cases is to query the INFORMATION_SCHEMA PARTITIONS table, as shown in this example:

    SELECT SUM(DATA_FREE)
        FROM  INFORMATION_SCHEMA.PARTITIONS
        WHERE TABLE_SCHEMA = 'mydb'
        AND   TABLE_NAME   = 'mytable';

    For more information, see Section 24.16, “The INFORMATION_SCHEMA PARTITIONS Table”.

  • Auto_increment

    The next AUTO_INCREMENT value.

  • Create_time

    When the table was created.

  • Update_time

    When the data file was last updated. For some storage engines, this value is NULL. For example, InnoDB stores multiple tables in its system tablespace and the data file timestamp does not apply. Even with file-per-table mode with each InnoDB table in a separate .ibd file, change buffering can delay the write to the data file, so the file modification time is different from the time of the last insert, update, or delete. For MyISAM, the data file timestamp is used; however, on Windows the timestamp is not updated by updates, so the value is inaccurate.

    Update_time displays a timestamp value for the last UPDATE, INSERT, or DELETE performed on InnoDB tables that are not partitioned. For MVCC, the timestamp value reflects the COMMIT time, which is considered the last update time. Timestamps are not persisted when the server is restarted or when the table is evicted from the InnoDB data dictionary cache.

    The Update_time column also shows this information for partitioned InnoDB tables.

  • Check_time

    When the table was last checked. Not all storage engines update this time, in which case, the value is always NULL.

    For partitioned InnoDB tables, Check_time is always NULL.

  • Collation

    The table default collation. The output does not explicitly list the table default character set, but the collation name begins with the character set name.

  • Checksum

    The live checksum value, if any.

  • Create_options

    Extra options used with CREATE TABLE. The original options from when CREATE TABLE was executed are retained and the options reported here may differ from the active table settings and options.

    Create_options shows partitioned if the table is partitioned. It also shows the ENCRYPTION option specified when creating or altering a file-per-table tablespace.

  • Comment

    The comment used when creating the table (or information as to why MySQL could not access the table information).

Notes
  • For NDB tables, the output of this statement shows appropriate values for the Avg_row_length and Data_length columns, with the exception that BLOB columns are not taken into account.

  • For NDB tables, Data_length includes data stored in main memory only; the Max_data_length and Data_free columns apply to Disk Data.

  • For NDB Cluster Disk Data tables, Max_data_length shows the space allocated for the disk part of a Disk Data table or fragment. (In-memory data resource usage is reported by the Data_length column.)

  • For MEMORY tables, the Data_length, Max_data_length, and Index_length values approximate the actual amount of allocated memory. The allocation algorithm reserves memory in large amounts to reduce the number of allocation operations.

  • For views, all columns displayed by SHOW TABLE STATUS are NULL except that Name indicates the view name and Comment says VIEW.

Table information is also available from the INFORMATION_SCHEMA TABLES table. See Section 24.25, “The INFORMATION_SCHEMA TABLES Table”.


User Comments
User comments in this section are, as the name implies, provided by MySQL users. The MySQL documentation team is not responsible for, nor do they endorse, any of the information provided here.
  Posted by Ivan Cachicatari on February 29, 2012
You can found a custom SHOW TABLE STATUS command based on INFORMATION_SCHEMA database at:
http://en.latindevelopers.com/ivancp/2012/a-better-show-table-status/
That stored procedure returns a result like this:

+----------------------------+--------+-------+---------+-----------------+
| Table Name | Engine | Rows | Size | Collation |
+----------------------------+--------+-------+---------+-----------------+
| actor | InnoDB | 200 | 0.03 Mb | utf8_general_ci |
| actor_info | [VIEW] | - | - | - |
| address | InnoDB | 589 | 0.09 Mb | utf8_general_ci |
| category | InnoDB | 16 | 0.02 Mb | utf8_general_ci |
| city | InnoDB | 427 | 0.06 Mb | utf8_general_ci |
| country | InnoDB | 109 | 0.02 Mb | utf8_general_ci |
| customer | InnoDB | 541 | 0.12 Mb | utf8_general_ci |
...

  Posted by NOT_FOUND NOT_FOUND on July 2, 2014
MySQL 5.6 finally speeds up SHOW TABLE STATUS in cases where it used to perform miserably. Example for one of our databases containing 112 InnoDB tables, some of which have millions of rows:

MySQL 5.5.30: 32 seconds
MySQL 5.6.16: 0.3 seconds
Sign Up Login You must be logged in to post a comment.