MySQL :: MySQL 8.4 Reference Manual :: 15.7.7.23 SHOW INDEX Statement (original) (raw)

15.7.7.23 SHOW INDEX Statement

SHOW [EXTENDED] {INDEX | INDEXES | KEYS}
    {FROM | IN} tbl_name
    [{FROM | IN} db_name]
    [WHERE expr]

SHOW INDEX returns table index information. The format resembles that of theSQLStatistics call in ODBC. This statement requires some privilege for any column in the table.

mysql> SHOW INDEX FROM City\G
*************************** 1. row ***************************
        Table: city
   Non_unique: 0
     Key_name: PRIMARY
 Seq_in_index: 1
  Column_name: ID
    Collation: A
  Cardinality: 4188
     Sub_part: NULL
       Packed: NULL
         Null:
   Index_type: BTREE
      Comment:
Index_comment:
      Visible: YES
   Expression: NULL
*************************** 2. row ***************************
        Table: city
   Non_unique: 1
     Key_name: CountryCode
 Seq_in_index: 1
  Column_name: CountryCode
    Collation: A
  Cardinality: 232
     Sub_part: NULL
       Packed: NULL
         Null:
   Index_type: BTREE
      Comment:
Index_comment:
      Visible: YES
   Expression: NULL

An alternative to _`tblname`_ FROM _`dbname`_ syntax is_dbname.tblname_. These two statements are equivalent:

SHOW INDEX FROM mytable FROM mydb;
SHOW INDEX FROM mydb.mytable;

The optional EXTENDED keyword causes the output to include information about hidden indexes that MySQL uses internally and are not accessible by users.

The WHERE clause can be given to select rows using more general conditions, as discussed inSection 28.8, “Extensions to SHOW Statements”.

SHOW INDEX returns the following fields:

Information about table indexes is also available from theINFORMATION_SCHEMA STATISTICS table. SeeSection 28.3.34, “The INFORMATION_SCHEMA STATISTICS Table”. The extended information about hidden indexes is available only using SHOW EXTENDED INDEX; it cannot be obtained from the STATISTICS table.

You can list a table's indexes with the mysqlshow -k_db_name_ tbl_name command.

SHOW INDEX includes the table's generated invisible key, if it has one, by default. You can cause this information to be suppressed in the statement's output by settingshow_gipk_in_create_table_and_information_schema = OFF. For more information, seeSection 15.1.20.11, “Generated Invisible Primary Keys”.