The TABLES
table provides information
about tables in databases.
The TABLES
table has these columns:
TABLE_CATALOG
The name of the catalog to which the table belongs. This value is always
def
.TABLE_SCHEMA
The name of the schema (database) to which the table belongs.
TABLE_NAME
The name of the table.
TABLE_TYPE
BASE TABLE
for a table,VIEW
for a view, orSYSTEM VIEW
for anINFORMATION_SCHEMA
table.The
TABLES
table does not listTEMPORARY
tables.ENGINE
The storage engine for the table. See The InnoDB Storage Engine, and 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
). ForMyISAM
tables,Dynamic
corresponds to what myisamchk -dvv reports asPacked
.InnoDB
table format is eitherRedundant
orCompact
when using theAntelope
file format, orCompressed
orDynamic
when using theBarracuda
file format.TABLE_ROWS
The number of rows. Some storage engines, such as
MyISAM
, store the exact count. For other storage engines, such asInnoDB
, this value is an approximation, and may vary from the actual value by as much as 40% to 50%. In such cases, useSELECT COUNT(*)
to obtain an accurate count.TABLE_ROWS
isNULL
forINFORMATION_SCHEMA
tables.For
InnoDB
tables, the row count is only a rough estimate used in SQL optimization. (This is also true if theInnoDB
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 space allocated for the clustered index, in bytes. Specifically, it is the clustered index size, in pages, multiplied by theInnoDB
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 space allocated for non-clustered indexes, in bytes. Specifically, it is the sum of non-clustered index sizes, in pages, multiplied by theInnoDB
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 theDATA_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 4.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 eachInnoDB
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. ForMyISAM
, 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 lastUPDATE
,INSERT
, orDELETE
performed onInnoDB
tables that are not partitioned. For MVCC, the timestamp value reflects theCOMMIT
time, which is considered the last update time. Timestamps are not persisted when the server is restarted or when the table is evicted from theInnoDB
data dictionary cache.The
UPDATE_TIME
column also shows this information for partitionedInnoDB
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 alwaysNULL
.TABLE_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_OPTIONS
showspartitioned
if the table is partitioned.CREATE_OPTIONS
shows theENCRYPTION
clause specified for tables created in file-per-table tablespaces.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_FORMAT
column.CREATE_OPTIONS
shows the row format that was specified in theCREATE TABLE
statement.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. The
CREATE_OPTIONS
column may show retained options.TABLE_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 theAVG_ROW_LENGTH
andDATA_LENGTH
columns, with the exception thatBLOB
columns are not taken into account.For
NDB
tables,DATA_LENGTH
includes data stored in main memory only; theMAX_DATA_LENGTH
andDATA_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 theDATA_LENGTH
column.)For
MEMORY
tables, theDATA_LENGTH
,MAX_DATA_LENGTH
, andINDEX_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
TABLES
columns areNULL
except thatTABLE_NAME
indicates the view name andTABLE_COMMENT
saysVIEW
.
Table information is also available from the
SHOW TABLE STATUS
and
SHOW TABLES
statements. See
SHOW TABLE STATUS Statement, and
SHOW TABLES Statement. The following statements are
equivalent:
SELECT
TABLE_NAME, ENGINE, VERSION, ROW_FORMAT, TABLE_ROWS, AVG_ROW_LENGTH,
DATA_LENGTH, MAX_DATA_LENGTH, INDEX_LENGTH, DATA_FREE, AUTO_INCREMENT,
CREATE_TIME, UPDATE_TIME, CHECK_TIME, TABLE_COLLATION, CHECKSUM,
CREATE_OPTIONS, TABLE_COMMENT
FROM INFORMATION_SCHEMA.TABLES
WHERE table_schema = 'db_name'
[AND table_name LIKE 'wild']
SHOW TABLE STATUS
FROM db_name
[LIKE 'wild']
The following statements are equivalent:
SELECT
TABLE_NAME, TABLE_TYPE
FROM INFORMATION_SCHEMA.TABLES
WHERE table_schema = 'db_name'
[AND table_name LIKE 'wild']
SHOW FULL TABLES
FROM db_name
[LIKE 'wild']