28.3.38 The INFORMATION_SCHEMA TABLES Table (original) (raw)

28.3.38 The INFORMATION_SCHEMA TABLES Table

The TABLES table provides information about tables in databases.

Columns in TABLES that represent table statistics hold cached values. Theinformation_schema_stats_expiry system variable defines the period of time before cached table statistics expire. The default is 86400 seconds (24 hours). If there are no cached statistics or statistics have expired, statistics are retrieved from storage engines when querying table statistics columns. To update cached values at any time for a given table, use ANALYZE TABLE. To always retrieve the latest statistics directly from storage engines, setinformation_schema_stats_expiry to 0. For more information, seeSection 10.2.3, “Optimizing INFORMATION_SCHEMA Queries”.

Note

If the innodb_read_only system variable is enabled, ANALYZE TABLE may fail because it cannot update statistics tables in the data dictionary, which useInnoDB. For ANALYZE TABLE operations that update the key distribution, failure may occur even if the operation updates the table itself (for example, if it is a MyISAM table). To obtain the updated distribution statistics, setinformation_schema_stats_expiry=0.

The TABLES table has these columns:

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

For more information, seeSection 28.3.21, “The INFORMATION_SCHEMA PARTITIONS Table”.

Notes

Table information is also available from theSHOW TABLE STATUS andSHOW TABLES statements. SeeSection 15.7.7.38, “SHOW TABLE STATUS Statement”, andSection 15.7.7.39, “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']