You can use the CREATE INDEX statement to create an index on a table.
Background
OceanBase Database allows you to create an index on both partitioned and non-partitioned tables. An index can be either a local index or a global index. In addition, it can either be a unique index or a normal index. A local unique index on a partitioned table must include a partitioning key of the table.
This topic describes how to create an index on a non-partitioned table. For information about how to create an index on a partitioned table, see Indexes on partitioned tables.
Syntax
In MySQL mode, you can use any of the following statements to create an index:
Statement 1
Use the CREATE TABLE statement to create an index.
CREATE [TEMPORARY] TABLE [IF NOT EXISTS] table_name
(table_definition_list) [table_option_list] [partition_option] [AS] select;
CREATE [TEMPORARY] TABLE [IF NOT EXISTS] table_name
LIKE table_name;
table_definition_list:
table_definition [, table_definition ...]
table_definition:
column_definition
| [CONSTRAINT [constraint_name]] PRIMARY KEY index_desc
| [CONSTRAINT [constraint_name]] UNIQUE {INDEX | KEY} [index_name] index_desc
| {INDEX | KEY} [index_name] index_desc
column_definition_list:
column_definition [, column_definition ...]
column_definition:
column_name data_type
[DEFAULT const_value] [AUTO_INCREMENT]
[NULL | NOT NULL] [[PRIMARY] KEY] [UNIQUE [KEY]] comment
index_desc:
(column_desc_list) [index_type] [index_option_list]
column_desc_list:
column_desc [, column_desc ...]
column_desc:
column_name [(length)] [ASC | DESC]
index_type:
USING BTREE
index_option_list:
index_option [ index_option ...]
index_option:
[GLOBAL | LOCAL]
| block_size
| compression
| STORING(column_name_list)
| comment
table_option_list:
table_option [ table_option ...]
table_option:
[DEFAULT] {CHARSET | CHARACTER SET} [=] charset_name
| [DEFAULT] COLLATE [=] collation_name
| primary_zone
| replica_num
| table_tablegroup
| block_size
| compression
| AUTO_INCREMENT [=] INT_VALUE
| comment
| DUPLICATE_SCOPE [=] "none|zone|region|cluster"
| LOCALITY [=] "locality description"
| ROW_FORMAT [=] REDUNDANT|COMPACT|DYNAMIC|COMPRESSED|DEFAULT
| PCTFREE [=] num
partition_option:
PARTITION BY HASH(expression)
[subpartition_option] PARTITIONS partition_count
| PARTITION BY KEY([column_name_list])
[subpartition_option] PARTITIONS partition_count
| PARTITION BY RANGE {(expression) | COLUMNS (column_name_list)}
[subpartition_option] (range_partition_list)
| PARTITION BY LIST {(expression) | COLUMNS (column_name_list)}
[subpartition_option] PARTITIONS partition_count
subpartition_option:
SUBPARTITION BY HASH(expression)
SUBPARTITIONS subpartition_count
| SUBPARTITION BY KEY(column_name_list)
SUBPARTITIONS subpartition_count
| SUBPARTITION BY RANGE {(expression) | COLUMNS (column_name_list)}
(range_subpartition_list)
| SUBPARTITION BY LIST(expression)
range_partition_list:
range_partition [, range_partition ...]
range_partition:
PARTITION partition_name
VALUES LESS THAN {(expression_list) | MAXVALUE}
range_subpartition_list:
range_subpartition [, range_subpartition ...]
range_subpartition:
SUBPARTITION subpartition_name
VALUES LESS THAN {(expression_list) | MAXVALUE}
expression_list:
expression [, expression ...]
column_name_list:
column_name [, column_name ...]
partition_name_list:
partition_name [, partition_name ...]
partition_count | subpartition_count:
INT_VALUE
Statement 2
Use the CREATE INDEX statement to create an index.
CREATE [UNIQUE] INDEX index_name ON table_name ( column_list ) [LOCAL | GLOBAL] [ PARTITION BY column_list PARTITIONS N ];
In a MySQL tenant, index names must be unique at the table level. You can use the SHOW INDEX statement to view the indexes on a table.
Statement 3
In MySQL mode, you can also use the ALTER TABLE statement to create an index.
ALTER TABLE table_name
ADD INDEX|KEY index_name ( column_list );
This statement allows you to create multiple indexes at a time. You can use either the INDEX or the KEY keyword.
Examples
Example 1
Create a table named
t_idx1.obclient> CREATE TABLE t_idx1( id int, name varchar(18), date date, PRIMARY KEY (id), index idx (date) );Query the indexes on the
t_idx1table.obclient> SHOW INDEX FROM t_idx1; +--------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+ | Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment | Index_comment | Visible | +--------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+ | t_idx1 | 0 | PRIMARY | 1 | id | A | NULL | NULL | NULL | | BTREE | available | | YES | | t_idx1 | 1 | idx | 1 | date | A | NULL | NULL | NULL | YES | BTREE | available | | YES | +--------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+ 2 rows in set
Example 2
Create a table named
t_idx2.obclient> CREATE TABLE t_idx2 (id int primary key, name varchar(10)); Query OK, 0 rows affectedAdd the
idxindex on thet_idx2table.obclient> CREATE INDEX idx ON t_idx2 (id, name); Query OK, 0 rows affectedQuery the indexes on the
t_idx2table.obclient> SHOW INDEX FROM t_idx2; +--------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+ | Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment | Index_comment | Visible | +--------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+ | t_idx2 | 0 | PRIMARY | 1 | id | A | NULL | NULL | NULL | | BTREE | available | | YES | | t_idx2 | 1 | idx | 1 | id | A | NULL | NULL | NULL | | BTREE | available | | YES | | t_idx2 | 1 | idx | 2 | name | A | NULL | NULL | NULL | YES | BTREE | available | | YES | +--------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+ 3 rows in set
Example 3
Create a table named
t_idx3.CREATE TABLE t_idx3( id int, name varchar(18), date date, PRIMARY KEY (id) );Add the
idxindex to thet_idx3table.obclient> ALTER TABLE t_idx3 ADD INDEX idx ( date ) ; Query OK, 0 rows affectedQuery the indexes on the
t_idx3table.obclient> SHOW INDEX FROM t_idx3; +--------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+ | Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment | Index_comment | Visible | +--------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+ | t_idx3 | 0 | PRIMARY | 1 | id | A | NULL | NULL | NULL | | BTREE | available | | YES | | t_idx3 | 1 | idx | 1 | date | A | NULL | NULL | NULL | YES | BTREE | available | | YES | +--------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+ 2 rows in set