Documentation Home
MySQL 5.6 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 31.2Mb
PDF (A4) - 31.3Mb
PDF (RPM) - 29.7Mb
HTML Download (TGZ) - 7.3Mb
HTML Download (Zip) - 7.4Mb
HTML Download (RPM) - 6.3Mb
Man Pages (TGZ) - 176.9Kb
Man Pages (Zip) - 286.9Kb
Info (Gzip) - 3.0Mb
Info (Zip) - 3.0Mb
Excerpts from this Manual ANALYZE TABLE Syntax

    TABLE tbl_name [, tbl_name] ...

ANALYZE TABLE performs a key distribution analysis and stores the distribution for the named table or tables. For MyISAM tables, this statement is equivalent to using myisamchk --analyze.

This statement requires SELECT and INSERT privileges for the table.

ANALYZE TABLE works with InnoDB, NDB, and MyISAM tables. It does not work with views.

ANALYZE TABLE is supported for partitioned tables, and you can use ALTER TABLE ... ANALYZE PARTITION to analyze one or more partitions; for more information, see Section 13.1.7, “ALTER TABLE Syntax”, and Section 19.3.4, “Maintenance of Partitions”.

During the analysis, the table is locked with a read lock for InnoDB and MyISAM.

By default, the server writes ANALYZE TABLE statements to the binary log so that they replicate to replication slaves. To suppress logging, specify the optional NO_WRITE_TO_BINLOG keyword or its alias LOCAL.


ANALYZE TABLE returns a result set with the columns shown in the following table.

Column Value
Table The table name
Op Always analyze
Msg_type status, error, info, note, or warning
Msg_text An informational message
Key Distribution Analysis

If the table has not changed since the last key distribution analysis, the table is not analyzed again.

MySQL uses the stored key distribution to decide the table join order for joins on something other than a constant. In addition, key distributions can be used when deciding which indexes to use for a specific table within a query.

For more information on how key distribution analysis works within InnoDB, see Section, “Configuring Persistent Optimizer Statistics Parameters” and Section, “Estimating ANALYZE TABLE Complexity for InnoDB Tables”. Also see Section, “Limits on InnoDB Tables”. In particular, if the innodb_stats_persistent system variable is enabled, you must run ANALYZE TABLE after loading substantial data into an InnoDB table, or creating a new index for one.

In MySQL 5.6.11 only, gtid_next must be set to AUTOMATIC before issuing this statement. (Bug #16062608, Bug #16715809, Bug #69045)

To check the stored key distribution cardinality, use the SHOW INDEX statement or the INFORMATION_SCHEMA.STATISTICS table. See Section, “SHOW INDEX Syntax”, and Section 21.21, “The INFORMATION_SCHEMA STATISTICS Table”.

User Comments
  Posted by James Day on July 26, 2004
Use mysqlcheck -Aa -uroot -p to run analyze table for all databases and tables (including InnoDB) on a running server. Available in MySQL 3.23.38 and later.
  Posted by Rob Blick on April 27, 2005
Note that ANALYZE TABLE requires SELECT and INSERT privileges, only (LOCK TABLES is not needed).
Sign Up Login You must be logged in to post a comment.