PolarDB-X支持创建局部索引和全局二级索引 (Global Secondary Index,GSI) ,同时支持删除这两种索引。本语法仅适用于AUTO模式数据库。
局部索引
关于局部索引,详情请参见CREATE INDEX Statement。
全局二级索引
关于全局二级索引基本原理,请参见全局二级索引。
语法
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 BY
HASH({column_name | partition_func(column_name)})
| KEY(column_list)
| RANGE{({column_name | partition_func(column_name)})
| RANGE COLUMNS(column_list)}
| LIST{({column_name | partition_func(column_name)})
| LIST COLUMNS(column_list)} }
partition_list_spec
# 分区函数定义
partition_func:
YEAR
| TO_DAYS
| TO_SECOND
| UNIX_TIMESTAMP
| MONTH
# 分区列表定义
partition_list_spec:
hash_partition_list
| range_partition_list
| list_partition_list
# Hash/Key分区表列定义
hash_partition_list:
PARTITIONS partition_count
# Range/Range Columns分区表列定义
range_partition_list:
range_partition [, range_partition ...]
range_partition:
PARTITION partition_name VALUES LESS THAN {(expr | value_list)} [partition_spec_options]
# List/List Columns分区表列定义
list_partition_list:
list_partition [, list_partition ...]
list_partition:
PARTITION partition_name VALUES IN (value_list) [partition_spec_options]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查看索引信息。
说明
关于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 |
+------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




