13.1.13 CREATE INDEX Syntax

    ON tbl_name (index_col_name,...)
    [index_option] ...

    col_name [(length)] [ASC | DESC]


    KEY_BLOCK_SIZE [=] value
  | index_type
  | WITH PARSER parser_name

CREATE INDEX is mapped to an ALTER TABLE statement to create indexes. See Section 13.1.7, “ALTER TABLE Syntax”. CREATE INDEX cannot be used to create a PRIMARY KEY; use ALTER TABLE instead. For more information about indexes, see Section 8.3.1, “How MySQL Uses Indexes”.

Normally, you create all indexes on a table at the time the table itself is created with CREATE TABLE. See Section 13.1.17, “CREATE TABLE Syntax”. This guideline is especially important for InnoDB tables, where the primary key determines the physical layout of rows in the data file. CREATE INDEX enables you to add indexes to existing tables.

A column list of the form (col1,col2,...) creates a multiple-column index. Index key values are formed by concatenating the values of the given columns.

Indexes can be created that use only the leading part of column values, using col_name(length) syntax to specify an index prefix length:

  • Prefixes can be specified for CHAR, VARCHAR, BINARY, and VARBINARY columns.

  • BLOB and TEXT columns also can be indexed, but a prefix length must be given.

  • Prefix lengths are given in characters for nonbinary string types and in bytes for binary string types. That is, index entries consist of the first length characters of each column value for CHAR, VARCHAR, and TEXT columns, and the first length bytes of each column value for BINARY, VARBINARY, and BLOB columns.

  • For spatial columns, prefix values cannot be given, as described later in this section.

The statement shown here creates an index using the first 10 characters of the name column:

CREATE INDEX part_of_name ON customer (name(10));

If names in the column usually differ in the first 10 characters, this index should not be much slower than an index created from the entire name column. Also, using column prefixes for indexes can make the index file much smaller, which could save a lot of disk space and might also speed up INSERT operations.

Prefix support and lengths of prefixes (where supported) are storage engine dependent. For example, a prefix can be up to 1000 bytes long for MyISAM tables, and 767 bytes for InnoDB tables. The NDB storage engine does not support prefixes (see Section, “Unsupported or Missing Features in MySQL Cluster”).


Prefix limits are measured in bytes, whereas the prefix length in CREATE INDEX statements is interpreted as number of characters for nonbinary data types (CHAR, VARCHAR, TEXT). Take this into account when specifying a prefix length for a column that uses a multibyte character set.

Beginning with MySQL 5.1.17, indexes on variable-width columns of NDBCLUSTER tables are created online; that is, without any table copying. The table is not locked against access from other MySQL Cluster API nodes, although it is locked against other operations on the same API node for the duration of the operation. This is done automatically by the server whenever it determines that it is possible to do so; you do not have to use any special SQL syntax or server options to cause it to happen.

In standard MySQL 5.1 releases, it is not possible to override the server when it determines that an index is to be created without table copying. In MySQL Cluster, you can create indexes offline (which causes the table to be locked to all API nodes in the cluster) using the OFFLINE keyword. The rules and limitations governing CREATE OFFLINE INDEX and CREATE ONLINE INDEX are the same as for ALTER OFFLINE TABLE ... ADD INDEX and ALTER ONLINE TABLE ... ADD INDEX. You cannot cause the noncopying creation of an index that would normally be created offline by using the ONLINE keyword: If it is not possible to perform the CREATE INDEX operation without table copying, the server ignores the ONLINE keyword. For more information, see Section, “ALTER TABLE Online Operations in MySQL Cluster”.


The ONLINE and OFFLINE keywords are available only in MySQL Cluster NDB 6.2.5, 6.3.2, and later MySQL Cluster releases; attempting to use these keywords in earlier MySQL Cluster releases or standard MySQL 5.1 releases results in a syntax error.

A UNIQUE index creates a constraint such that all values in the index must be distinct. An error occurs if you try to add a new row with a key value that matches an existing row. For all engines, a UNIQUE index permits multiple NULL values for columns that can contain NULL. If you specify a prefix value for a column in a UNIQUE index, the column values must be unique within the prefix.

FULLTEXT indexes are supported only for MyISAM tables and can include only CHAR, VARCHAR, and TEXT columns. Indexing always happens over the entire column; column prefix indexing is not supported and any prefix length is ignored if specified. See Section 12.9, “Full-Text Search Functions”, for details of operation.

The MyISAM, InnoDB, NDB, and ARCHIVE storage engines support spatial columns such as (POINT and GEOMETRY. (Section 11.5, “Extensions for Spatial Data”, describes the spatial data types.) However, support for spatial column indexing varies among engines. Spatial and nonspatial indexes are available according to the following rules.

Spatial indexes (created using SPATIAL INDEX) have these characteristics:

  • Available only for MyISAM tables. Specifying SPATIAL INDEX for other storage engines results in an error.

  • Indexed columns must be NOT NULL.

  • In MySQL 5.1, column prefix lengths are prohibited. The full width of each column is indexed.

Characteristics of nonspatial indexes (created with INDEX, UNIQUE, or PRIMARY KEY):

  • Permitted for any storage engine that supports spatial columns except ARCHIVE.

  • Columns can be NULL unless the index is a primary key.

  • For each spatial column in a non-SPATIAL index except POINT columns, a column prefix length must be specified. (This is the same requirement as for indexed BLOB columns.) The prefix length is given in bytes.

  • The index type for a non-SPATIAL index depends on the storage engine. Currently, B-tree is used.

In MySQL 5.1:

  • You can add an index on a column that can have NULL values only if you are using the MyISAM, InnoDB, or MEMORY storage engine.

  • You can add an index on a BLOB or TEXT column only if you are using the MyISAM, or InnoDB storage engine.

An index_col_name specification can end with ASC or DESC. These keywords are permitted for future extensions for specifying ascending or descending index value storage. Currently, they are parsed but ignored; index values are always stored in ascending order.

As of MySQL 5.1.10, index options can be given following the index column list. An index_option value can be any of the following:

  • KEY_BLOCK_SIZE [=] value

    Optionally specifies the size in bytes to use for index key blocks. The value is treated as a hint; a different size could be used if necessary.


    KEY_BLOCK_SIZE is only supported at the table level for InnoDB. See Section 13.1.17, “CREATE TABLE Syntax”.

  • index_type

    Some storage engines permit you to specify an index type when creating an index. The permissible index type values supported by different storage engines are shown in the following table. Where multiple index types are listed, the first one is the default when no index type specifier is given.

    Storage EnginePermissible Index Types
    NDBBTREE, HASH (see note in text)


    CREATE INDEX id_index ON lookup (id) USING BTREE;

    BTREE indexes are implemented by the NDB storage engine as T-tree indexes.


    For indexes on NDB table columns, the USING option can be specified only for a unique index or primary key. USING HASH prevents the creation of an ordered index; otherwise, creating a unique index or primary key on an NDB table automatically results in the creation of both an ordered index and a hash index, each of which indexes the same set of columns.

    For unique indexes that include one or more NULL columns of an NDB table, the hash index can be used only to look up literal values, which means that IS [NOT] NULL conditions require a full scan of the table. One workaround is to make sure that a unique index using one or more NULL columns on such a table is always created in such a way that it includes the ordered index; that is, avoid employing USING HASH when creating the index.

    The index_type clause cannot be used together with SPATIAL INDEX.

    If you specify an index type that is not valid for a given storage engine, but there is another index type available that the engine can use without affecting query results, the engine uses the available type. The parser recognizes RTREE as a type name, but currently this cannot be specified for any storage engine.

    Before MySQL 5.1.10, this option can be given only before the ON tbl_name clause. Use of the option in this position is deprecated as of 5.1.10 and support for it there will be removed in a future MySQL release. If an index_type option is given in both the earlier and later positions, the final option applies.

    TYPE type_name is recognized as a synonym for USING type_name. However, USING is the preferred form.

  • WITH PARSER parser_name

    This option can be used only with FULLTEXT indexes. It associates a parser plugin with the index if full-text indexing and searching operations need special handling. See Section 22.2, “The MySQL Plugin API”, for details on creating plugins.

Download this Manual
User Comments
  Posted by Matthijs Lambooy on March 14, 2006
Only 16 fields are allowed in one fulltext index.
  Posted by Andrew Krantz on April 27, 2006
Be careful when you run this because MySQL will LOCK the table for WRITES during the index creation. Building the index can take a while on large tables even if the column is empty (all nulls).
  Posted by Nathan Moon on May 11, 2007
From my experience, adding an index to a table locks the table for reads as well as writes.
  Posted by Varun Grover on September 28, 2007
Running SELECTs on a table on which an index is being created may block because the server may need to use the index for looking-up records; and, the index is locked because it is being written to.
  Posted by David OBrien on March 26, 2009
Since there is no

We made this sproc to do it...

DROP PROCEDURE IF EXISTS `create_index_if_not_exists`$$

CREATE DEFINER=`user`@`%` PROCEDURE `create_index_if_not_exists`(table_name_vc varchar(50), index_name_vc varchar(50), field_list_vc varchar(200))

set @Index_cnt = (
select count(1) cnt
WHERE table_name = table_name_vc
and index_name = index_name_vc

IF ifnull(@Index_cnt,0) = 0 THEN set @index_sql = concat('Alter table ',table_name_vc,' ADD INDEX ',index_name_vc,'(',field_list_vc,');');

PREPARE stmt FROM @index_sql;




use it like...

call create_index_if_not_exists('tablename','indexname','thisfield,thatfield');
  Posted by Lincoln Rickwood on June 24, 2011
Here's an alternative stored procedure (Sorry about the lack of indentation, the comment box seems to strip leading spaces)...

delimiter //
drop procedure if exists AddTableIndex //
create procedure AddTableIndex
( in schemaName varchar(128) -- If null use name of current schema;
, in tableName varchar(128) -- If null an exception will be thrown.
, in indexName varchar(128) -- If null an exception will be thrown.
, in indexDefinition varchar(1024) -- E.g. '(expireTS_ ASC)'
, in ifPresent enum('leaveUnchanged', 'dropAndReplace') -- null=leaveUnchanged.
, out outcome tinyint(1) -- 0=unchanged, 1=replaced, 4=added.
declare doDrop tinyint(1) default null;
declare doAdd tinyint(1) default null;
declare tmpSql varchar(4096) default '';

set schemaName = coalesce(schemaName, schema());
set ifPresent = coalesce(ifPresent, 'leaveUnchanged');
if exists
WHERE table_schema = schemaName
AND table_name = tableName
AND index_name = indexName
if (ifPresent = 'leaveUnchanged')
set doDrop = 0;
set doAdd = 0;
set outcome = 0;
elseif (ifPresent = 'dropAndReplace')
set doDrop = 1;
set doAdd = 1;
set outcome = 1;
end if;
set doDrop = 0;
set doAdd = 1;
set outcome = 4;
end if;

if (doDrop = 1)
set tmpSql = concat( 'alter table `', schemaName, '`.`', tableName, '` drop index `', indexName, '` ');
set @sql = tmpSql;
prepare tmp_stmt from @sql;
execute tmp_stmt;
deallocate prepare tmp_stmt;
end if;

if (doAdd = 1)
set tmpSql = concat( 'alter table `', schemaName, '`.`', tableName, '` add index `', indexName, '` ', indexDefinition);
set @sql = tmpSql;
prepare tmp_stmt from @sql;
execute tmp_stmt;
deallocate prepare tmp_stmt;
end if;

end; //

  Posted by James Greene on May 3, 2013
OK, so I'm a bit green myself when it comes to optimizing MySQL. So, I'm giving this little bit of advice to the other newbs out there:

Indexing a LARGE amount of data, this can take hours. Thankfully, I used on a test database. Please be careful, if you plan on adding index on a production database. :-/
  Posted by Jonathan DeLanders on October 16, 2014
Specify ALGORITHM=INPLACE when adding an index to production. I know that mysql will choose INPLACE automatically when its enabled, but it doesnt warn you if it cant. IMHO the copy algorithm is never desired on a busy system ( typically dba's use percona toolkit or rebuild tables instead ). By specifying this you will at least get an error instead of locking up your server.
Sign Up Login You must be logged in to post a comment.