SHOW TABLE STATUS
    [{FROM | IN} db_name]
    [LIKE 'pattern' | WHERE expr]
        SHOW TABLE STATUS works like
        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 28.8, “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 17, The InnoDB Storage Engine, and Chapter 18, Alternative Storage Engines. - For partitioned tables, - Engineshows the name of the storage engine used by all partitions.
- Version- This column is unused. With the removal of - .frmfiles in MySQL 8.0, this column now reports a hardcoded value of- 10, which was the last- .frmfile version used in MySQL 5.7.
- Row_format- The row-storage format ( - Fixed,- Dynamic,- Compressed,- Redundant,- Compact). For- MyISAMtables,- Dynamiccorresponds to what myisamchk -dvv reports as- Packed.
- 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 - Rowsvalue is- NULLfor- INFORMATION_SCHEMAtables.- For - InnoDBtables, the row count is only a rough estimate used in SQL optimization. (This is also true if the- InnoDBtable is partitioned.)
- Avg_row_length- The average row length. 
- Data_length- For - MyISAM,- Data_lengthis the length of the data file, in bytes.- For - InnoDB,- Data_lengthis the approximate amount of space allocated for the clustered index, in bytes. Specifically, it is the clustered index size, in pages, multiplied by the- InnoDBpage size.- Refer to the notes at the end of this section for information regarding other storage engines. 
- Max_data_length- For - MyISAM,- Max_data_lengthis 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_lengthis the length of the index file, in bytes.- For - InnoDB,- Index_lengthis the approximate amount of space allocated for non-clustered indexes, in bytes. Specifically, it is the sum of non-clustered index sizes, in pages, multiplied by the- InnoDBpage 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. - InnoDBtables 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_freeshows 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_lengthcolumn.)- 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- PARTITIONStable, 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 28.3.21, “The INFORMATION_SCHEMA PARTITIONS Table”. 
- Auto_increment- The next - AUTO_INCREMENTvalue.
- 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,- InnoDBstores multiple tables in its system tablespace and the data file timestamp does not apply. Even with file-per-table mode with each- InnoDBtable in a separate- .ibdfile, 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_timedisplays a timestamp value for the last- UPDATE,- INSERT, or- DELETEperformed on- InnoDBtables that are not partitioned. For MVCC, the timestamp value reflects the- COMMITtime, which is considered the last update time. Timestamps are not persisted when the server is restarted or when the table is evicted from the- InnoDBdata dictionary cache.
- 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 - InnoDBtables,- Check_timeis 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.- Create_optionsshows- partitionedfor a partitioned table.- Create_optionsshows the- ENCRYPTIONclause for file-per-table tablespaces if the table is encrypted or if the specified encryption differs from the schema encryption. The encryption clause is not shown for tables created in general tablespaces. To identify encrypted file-per-table and general tablespaces, query the- INNODB_TABLESPACES- ENCRYPTIONcolumn.- When creating a table with strict mode disabled, the storage engine's default row format is used if the specified row format is not supported. The actual row format of the table is reported in the - Row_formatcolumn.- Create_optionsshows the row format that was specified in the- CREATE TABLEstatement.- When altering the storage engine of a table, table options that are not applicable to the new storage engine are retained in the table definition to enable reverting the table with its previously defined options to the original storage engine, if necessary. - Create_optionsmay show retained options.
- Comment- The comment used when creating the table (or information as to why MySQL could not access the table information). 
Notes
- For - InnoDBtables,- SHOW TABLE STATUSdoes not give accurate statistics except for the physical size reserved by the table. The row count is only a rough estimate used in SQL optimization.
- For - NDBtables, the output of this statement shows appropriate values for the- Avg_row_lengthand- Data_lengthcolumns, with the exception that- BLOBcolumns are not taken into account.
- For - NDBtables,- Data_lengthincludes data stored in main memory only; the- Max_data_lengthand- Data_freecolumns apply to Disk Data.
- For NDB Cluster Disk Data tables, - Max_data_lengthshows the space allocated for the disk part of a Disk Data table or fragment. (In-memory data resource usage is reported by the- Data_lengthcolumn.)
- For - MEMORYtables, the- Data_length,- Max_data_length, and- Index_lengthvalues approximate the actual amount of allocated memory. The allocation algorithm reserves memory in large amounts to reduce the number of allocation operations.
- For views, most columns displayed by - SHOW TABLE STATUSare 0 or- NULLexcept that- Nameindicates the view name,- Create_timeindicates the creation time, and- Commentsays- VIEW.
        Table information is also available from the
        INFORMATION_SCHEMA
        TABLES table. See
        Section 28.3.38, “The INFORMATION_SCHEMA TABLES Table”.