MySQL :: MySQL 8.4 Reference Manual :: 15.7.3.2 CHECK TABLE Statement (original) (raw)

15.7.3.2 CHECK TABLE Statement

CHECK TABLE tbl_name [, tbl_name] ... [option] ...

option: {
    FOR UPGRADE
  | QUICK
  | FAST
  | MEDIUM
  | EXTENDED
  | CHANGED
}

CHECK TABLE checks a table or tables for errors. CHECK TABLE can also check views for problems, such as tables that are referenced in the view definition that no longer exist.

To check a table, you must have some privilege for it.

CHECK TABLE works forInnoDB,MyISAM,ARCHIVE, andCSV tables.

Before running CHECK TABLE onInnoDB tables, seeCHECK TABLE Usage Notes for InnoDB Tables.

CHECK TABLE is supported for partitioned tables, and you can use ALTER TABLE ... CHECK PARTITION to check one or more partitions; for more information, see Section 15.1.9, “ALTER TABLE Statement”, andSection 26.3.4, “Maintenance of Partitions”.

CHECK TABLE ignores virtual generated columns that are not indexed.

CHECK TABLE Output

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

Column Value
Table The table name
Op Always check
Msg_type status, error,info, note, orwarning
Msg_text An informational message

The statement might produce many rows of information for each checked table. The last row has a Msg_type value of status and theMsg_text normally should beOK. Table is already up to date means that the storage engine for the table indicated that there was no need to check the table.

Checking Version Compatibility

The FOR UPGRADE option checks whether the named tables are compatible with the current version of MySQL. With FOR UPGRADE, the server checks each table to determine whether there have been any incompatible changes in any of the table's data types or indexes since the table was created. If not, the check succeeds. Otherwise, if there is a possible incompatibility, the server runs a full check on the table (which might take some time).

Incompatibilities might occur because the storage format for a data type has changed or because its sort order has changed. Our aim is to avoid these changes, but occasionally they are necessary to correct problems that would be worse than an incompatibility between releases.

FOR UPGRADE discovers these incompatibilities:

Checking Data Consistency

The following table shows the other check options that can be given. These options are passed to the storage engine, which may use or ignore them.

Type Meaning
QUICK Do not scan the rows to check for incorrect links. Applies toInnoDB and MyISAM tables and views.
FAST Check only tables that have not been closed properly. Ignored forInnoDB; applies only toMyISAM tables and views.
CHANGED Check only tables that have been changed since the last check or that have not been closed properly. Ignored forInnoDB; applies only toMyISAM tables and views.
MEDIUM Scan rows to verify that deleted links are valid. This also calculates a key checksum for the rows and verifies this with a calculated checksum for the keys. Ignored forInnoDB; applies only toMyISAM tables and views.
EXTENDED Do a full key lookup for all keys for each row. This ensures that the table is 100% consistent, but takes a long time. Ignored for InnoDB; applies only toMyISAM tables and views.

You can combine check options, as in the following example that does a quick check on the table to determine whether it was closed properly:

CHECK TABLE test_table FAST QUICK;

Note

If CHECK TABLE finds no problems with a table that is marked as“corrupted” or “not closed properly”, CHECK TABLE may remove the mark.

If a table is corrupted, the problem is most likely in the indexes and not in the data part. All of the preceding check types check the indexes thoroughly and should thus find most errors.

To check a table that you assume is okay, use no check options or the QUICK option. The latter should be used when you are in a hurry and can take the very small risk that QUICK does not find an error in the data file. (In most cases, under normal usage, MySQL should find any error in the data file. If this happens, the table is marked as “corrupted” and cannot be used until it is repaired.)

FAST and CHANGED are mostly intended to be used from a script (for example, to be executed from cron) to check tables periodically. In most cases, FAST is to be preferred over CHANGED. (The only case when it is not preferred is when you suspect that you have found a bug in the MyISAM code.)

EXTENDED is to be used only after you have run a normal check but still get errors from a table when MySQL tries to update a row or find a row by key. This is very unlikely if a normal check has succeeded.

Use of CHECK TABLE ... EXTENDED might influence execution plans generated by the query optimizer.

Some problems reported by CHECK TABLE cannot be corrected automatically:

CHECK TABLE Usage Notes for InnoDB Tables

The following notes apply toInnoDB tables:

CHECK TABLE Usage Notes for MyISAM Tables

The following notes apply toMyISAM tables: