全部產品
Search
文件中心

PolarDB:CREATE INDEX(AUTO模式文法)

更新時間:Jul 06, 2024

PolarDB-X支援建立局部索引和全域二級索引 (Global Secondary Index,GSI) ,同時支援刪除這兩種索引。本文法僅適用於AUTO模式資料庫。

局部索引

關於局部索引,詳情請參見CREATE INDEX Statement

注意事項

若全域索引要使用二級分區的相關功能,執行個體版本必須為5.4.17-16952556及以上

全域二級索引

關於全域二級索引基本原理,請參見全域二級索引

文法

CREATE [UNIQUE]
    GLOBAL INDEX index_name [index_type]    
    ON tbl_name (index_sharding_col_name,...)    
    global_secondary_index_option 
    [index_option] 
    [algorithm_option | lock_option] ...    
# 全域二級索引特有文法,具體說明請參見CREATE TABLE文檔  
global_secondary_index_option:   
    [COVERING (col_name,...)]
    [partition_options]
    [VISIBLE|INVISIBLE]

# 分區定義
partition_options:
	partition_columns_definition
	[subpartition_columns_definition]
	[subpartition_specs_definition]/*用於定義模板化二級分區*/ 
  partition_specs_definition 

# 一級分區的分區列定義
partition_columns_definition:
		PARTITION BY
          HASH({column_name | partition_func(column_name)}) partitions_count
        | KEY(column_list) partitions_count
        | RANGE({column_name | partition_func(column_name)}) 
        | RANGE COLUMNS(column_list)
        | LIST({column_name | partition_func(column_name)}) 
        | LIST COLUMNS(column_list)

# 二級分區的分區列定義
subpartition_columns_definition:
		SUBPARTITION BY
          HASH({column_name | partition_func(column_name)}) subpartitions_count
        | KEY(column_list) subpartitions_count
        | RANGE({column_name | partition_func(column_name)}) 
        | RANGE COLUMNS(column_list)
        | LIST({column_name | partition_func(column_name)})
        | LIST COLUMNS(column_list)

partitions_count:
   PARTITIONS partition_count

subpartitions_count:
   SUBPARTITIONS partition_count

# 分區函數定義
partition_func:
    YEAR
  | TO_DAYS
  | TO_MONTHS
  | TO_WEEKS
  | TO_SECOND
  | UNIX_TIMESTAMP
  | MONTH
  | DAYOFWEEK
  | DAYOFMONTH
  | DAYOFYEAR
  | SUBSTR
  | SUBSTRING


# 一級分區的三種分區類型定義
partition_specs_definition:
	hash_partition_list
  | range_partition_list
  | list_partition_list

# 二級分區的三種分區類型定義
subpartition_specs_definition:
	hash_subpartition_list
  | range_subpartition_list
  | list_subpartition_list

# 一級分區的Hash/Key分區定義
hash_partition_list:
	  /*hash允許不指定各個具體分區定義*/
	| ( hash_partition [, hash_partition, ...] )

hash_partition:
    PARTITION partition_name [partition_spec_options] /*適用於純一級分區或使用模板化子分區*/
  | PARTITION partition_name subpartitions_count [subpartition_specs_definition] /*適用於定義一級分區下的非模板化子分區*/

# 二級級分區的Hash/Key分區定義
hash_subpartition_list:
  | empty
  | ( hash_subpartition [, hash_subpartition, ...] )

hash_subpartition:
	SUBPARTITION subpartition_name [partition_spec_options]

# 一級分區的Range/Range Columns分區定義
range_partition_list:
    ( range_partition [, range_partition, ... ] )

range_partition:
    	PARTITION partition_name VALUES LESS THAN (range_bound_value) [partition_spec_options] /*適用於純一級分區或使用模板化子分區*/
    |	PARTITION partition_name VALUES LESS THAN (range_bound_value) [[subpartitions_count] [subpartition_specs_definition]] /*適用於定義一級分區下的非模板化子分區*/
   
# 二級分區的Range/Range Columns分區定義
range_subpartition_list:
	( range_subpartition [, range_subpartition, ... ] )

range_subpartition:
    SUBPARTITION subpartition_name VALUES LESS THAN (range_bound_value) [partition_spec_options]
  
range_bound_value:
	  maxvalue /*適用於定義range的maxvalue分區*/
	| expr /*適用於使用單個分區列時range邊界值*/
	| value_list /*適用於使用多個分區列時range邊界值*/

# 一級分區的List/List Columns分區定義
list_partition_list:
    (list_partition [, list_partition ...])

list_partition:
    	PARTITION partition_name VALUES IN (list_bound_value) [partition_spec_options] /*適用於純一級分區或使用模板化子分區*/
    |	PARTITION partition_name VALUES IN (list_bound_value) [[subpartitions_count] [subpartition_specs_definition]] /*適用於定義一級分區下的非模板化子分區*/

# 二級分區的List/List Columns分區定義
list_subpartition_list:
	(list_subpartition [, list_subpartition ...])

list_subpartition:
	SUBPARTITION subpartition_name VALUES IN (list_bound_value) [partition_spec_options]

list_bound_value:
		default  /*適用於定義list的default分區*/
	|	value_set

value_set:
	  value_list  /*適用於使用單個分區列時values集合*/
	| (value_list) [, (value_list), ...] /*適用於使用多個分區列時的values集合*/

value_list:
	value [, value, ...]

partition_spec_options:
	    [[STORAGE] ENGINE [=] engine_name]
        [COMMENT [=] 'string']
        [LOCALITY [=] locality_option]

table_option:
 	    [[STORAGE] ENGINE [=] engine_name]
        [COMMENT [=] 'string']
        [{CHARSET | CHARACTER SET} [=] charset]
        [COLLATE [=] collation]
        [TABLEGROUP [=] table_group_id]
        [LOCALITY [=] locality_option]  

locality_option:
    'dn=storage_inst_id_list'
    
storage_inst_id_list:
    storage_inst_id[,storage_inst_id_list]

local_partition_definition:
		LOCAL PARTITION BY RANGE (column_name)
    [STARTWITH 'yyyy-MM-dd']
    INTERVAL interval_count [YEAR|MONTH|DAY]
    [EXPIRE AFTER expire_after_count]
    [PRE ALLOCATE pre_allocate_count]
    [PIVOTDATE pivotdate_func]
    [DISABLE SCHEDULE]
    
pivotdate_func:
		NOW()
  |	DATE_ADD(...)
  | DATE_SUB(...)

CREATE GLOBAL INDEX系列文法用於在建表後添加GSI,該系列文法在MySQL文法上新引入了GLOBAL關鍵字,用於指定添加的索引類型為GSI。目前建表後建立GSI存在一定限制,關於GSI的限制與約定,詳情請參見如何使用全域二級索引

關於全域二級索引定義子句的詳細說明,請參見CREATE TABLE(DRDS模式)

樣本

下面以建立普通全域二級索引為例,介紹如何在建表後建立GSI。

# 先建立表
CREATE TABLE t_order (
  `id` bigint(11) NOT NULL AUTO_INCREMENT,
  `order_id` varchar(20) DEFAULT NULL,
  `buyer_id` varchar(20) DEFAULT NULL,
  `seller_id` varchar(20) DEFAULT NULL,
  `order_snapshot` longtext DEFAULT NULL,
  `order_detail` longtext DEFAULT NULL,
  PRIMARY KEY (`id`),
  KEY `l_i_order` (`order_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 partition by hash(`order_id`) partitions 16;
# 再建立全域二級索引
CREATE GLOBAL INDEX `g_i_seller` ON t_order (`seller_id`) partition by hash(`seller_id`) partitions 16;
  • 主表:”t_order“是分區表,分區的拆分方式為按照”order_id“列進行雜湊。

  • 索引表:”g_i_seller“按照”seller_id“列進行雜湊,指定覆蓋列為”order_snapshot“。

  • 索引定義子句:GLOBAL INDEX `g_i_seller` ON t_order (`seller_id`) partition by hash(`seller_id`) partitions 16

通過SHOW INDEX查看索引資訊,包含拆分鍵order_id上的局部索引,seller_id、id和order_id上的GSI,其中seller_id為索引表的拆分鍵,id和order_id為預設的覆蓋列(主鍵和主表的拆分鍵)。

說明

關於GSI的限制與約定,詳情請參見如何使用全域二級索引,SHOW INDEX詳細說明,請參見SHOW INDEX

show index from t_order;

返回資訊如下:

+--------------------+------------+-----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+---------------+
| Table              | Non_unique | Key_name  | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment | Index_comment |
+--------------------+------------+-----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+---------------+
| t_order_****_00000 |          0 | PRIMARY   |            1 | id          | A         |           0 |     NULL | NULL   |      | BTREE      |         |               |
| t_order_****_00000 |          1 | l_i_order |            1 | order_id    | A         |           0 |     NULL | NULL   | YES  | BTREE      |         |               |
+--------------------+------------+-----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+---------------+
2 rows in set (0.02 sec)

通過SHOW GLOBAL INDEX可以單獨查看GSI資訊,詳情請參見SHOW GLOBAL INDEX

show global index from t_order;
+---------------------+---------+------------+------------+-------------+----------------+------------+------------------+---------------------+--------------------+------------------+---------------------+--------------------+--------+
| SCHEMA              | TABLE   | NON_UNIQUE | KEY_NAME   | INDEX_NAMES | COVERING_NAMES | INDEX_TYPE | DB_PARTITION_KEY | DB_PARTITION_POLICY | DB_PARTITION_COUNT | TB_PARTITION_KEY | TB_PARTITION_POLICY | TB_PARTITION_COUNT | STATUS |
+---------------------+---------+------------+------------+-------------+----------------+------------+------------------+---------------------+--------------------+------------------+---------------------+--------------------+--------+
| ZZY3_DRDS_LOCAL_APP | t_order | 1          | g_i_seller | seller_id   | id, order_id   | NULL       | seller_id        | HASH                | 4                  |                  | NULL                | NULL               | PUBLIC |
+---------------------+---------+------------+------------+-------------+----------------+------------+------------------+---------------------+--------------------+------------------+---------------------+--------------------+--------+  

查看索引表的結構,索引表包含主表的主鍵、分庫分表鍵、預設的覆蓋列和自訂覆蓋列,主鍵列去除了AUTO_INCREMENT屬性,並且去除了主表中的局部索引。

show create table g_i_seller;
+------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Table      | Create Table                                                                                                                                                                                                                                                                                  |
+------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| g_i_seller | CREATE TABLE `g_i_seller` (
  `id` bigint(11) NOT NULL,
  `order_id` varchar(20) DEFAULT NULL,
  `seller_id` varchar(20) DEFAULT NULL,
  PRIMARY KEY (`id`),
  KEY `auto_shard_key_seller_id` (`seller_id`) USING BTREE
) ENGINE=InnoDB DEFAULT CHARSET=utf8 partition by hash(`seller_id`) partitions 16 |
+------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+