备注:测试数据库版本为MySQL 8.0
这个blog我们来聊聊MySQL 索引相关操作
Table of Contents
一.创建索引
语法:
CREATE [UNIQUE | FULLTEXT | SPATIAL] INDEX index_name [index_type] ON tbl_name (key_part,...) [index_option] [algorithm_option | lock_option] ... key_part: {col_name [(length)] | (expr)} [ASC | DESC] index_option: { KEY_BLOCK_SIZE [=] value | index_type | WITH PARSER parser_name | COMMENT 'string' | {VISIBLE | INVISIBLE} } index_type: USING {BTREE | HASH} algorithm_option: ALGORITHM [=] {DEFAULT | INPLACE | COPY} lock_option: LOCK [=] {DEFAULT | NONE | SHARED | EXCLUSIVE}
复制
1.1 前缀索引
前缀索引可以使用在 CHAR, VARCHAR, BINARY, and VARBINARY 类型的列上
当列的类型为 BLOB和TEXT的时候,必须InnoDB, MyISAM, and BLACKHOLE的表,而且必须指定长度
当要索引的列字符很多时 索引则会很大且变慢
( 可以只索引列开始的部分字符串 节约索引空间 从而提高索引效率 )
原则: 降低重复的索引值
通过前缀索引找到对应的行,然后通过where过滤掉值不同的行,可以找到准确的数据
create table t1(id int,name varchar(100)); insert into t1 (id,name) values (1,'abcdefghijklmn'); insert into t1 (id,name) values (1,'abcdefghijklmnopq'); -- 创建前缀索引 create index i_t1_partname on t1(name(10));
复制
测试记录
mysql> create table t1(id int,name varchar(100)); Query OK, 0 rows affected (0.03 sec) mysql> mysql> insert into t1 (id,name) values (1,'abcdefghijklmn'); Query OK, 1 row affected (0.01 sec) mysql> insert into t1 (id,name) values (1,'abcdefghijklmnopq'); Query OK, 1 row affected (0.01 sec) mysql> create index i_t1_partname on t1(name(10)); Query OK, 0 rows affected (0.02 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql> select * from t1; +------+-------------------+ | id | name | +------+-------------------+ | 1 | abcdefghijklmn | | 1 | abcdefghijklmnopq | +------+-------------------+ 2 rows in set (0.00 sec) mysql> mysql> select * from t1 where name = 'abcdefghijklmn'; +------+----------------+ | id | name | +------+----------------+ | 1 | abcdefghijklmn | +------+----------------+ 1 row in set (0.00 sec)
复制
text列前缀索引
create table t2(id int,name text); insert into t2 values(1,'aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa'); insert into t2 values(1,'bbbbbbbbbbbbbbbbbbbbbbbbbbbbbbb'); create index i_t2_name on t2(name); create index i_t2_name on t2(name(10));
复制
测试记录
mysql> mysql> create table t2(id int,name text); Query OK, 0 rows affected (0.02 sec) mysql> insert into t2 values(1,'aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa'); Query OK, 1 row affected (0.01 sec) mysql> insert into t2 values(1,'bbbbbbbbbbbbbbbbbbbbbbbbbbbbbbb'); Query OK, 1 row affected (0.01 sec) mysql> mysql> create index i_t2_name on t2(name); ERROR 1170 (42000): BLOB/TEXT column 'name' used in key specification without a key length mysql> mysql> create index i_t2_name on t2(name(10)); Query OK, 0 rows affected (0.02 sec) Records: 0 Duplicates: 0 Warnings: 0
复制
1.2 函数索引
create table t3(id int,name varchar(100),index idx1 ((substring(name, 1, 10)))); show create table t3\G insert into t3 values (1,'aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa'); insert into t3 values (1,'bbbbbbbbbbbbbbbbbbbbbbbbbbbbbbbbbbb'); insert into t3 values (1,'ccccccccccccccccccccccccccccccccccccc'); explain select * from t3 where substring(name,1,10) = 'aaaaaaaaaa';
复制
测试记录:
mysql> create table t3(id int,name varchar(100),index idx1 ((substring(name, 1, 10)))); Query OK, 0 rows affected (0.03 sec) mysql> show create table t3\G *************************** 1. row *************************** Table: t3 Create Table: CREATE TABLE `t3` ( `id` int DEFAULT NULL, `name` varchar(100) DEFAULT NULL, KEY `idx1` ((substr(`name`,1,10))) ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.00 sec) mysql> mysql> insert into t3 values (1,'aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa'); Query OK, 1 row affected (0.01 sec) mysql> insert into t3 values (1,'bbbbbbbbbbbbbbbbbbbbbbbbbbbbbbbbbbb'); Query OK, 1 row affected (0.01 sec) mysql> insert into t3 values (1,'ccccccccccccccccccccccccccccccccccccc'); Query OK, 1 row affected (0.01 sec) mysql> -- where后面带 substring是可以用到索引的 mysql> explain select * from t3 where substring(name,1,10) = 'aaaaaaaaaa'; +----+-------------+-------+------------+------+---------------+------+---------+-------+------+----------+-------+ | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra | +----+-------------+-------+------------+------+---------------+------+---------+-------+------+----------+-------+ | 1 | SIMPLE | t3 | NULL | ref | idx1 | idx1 | 33 | const | 1 | 100.00 | NULL | +----+-------------+-------+------------+------+---------------+------+---------+-------+------+----------+-------+ 1 row in set, 1 warning (0.00 sec)
复制
1.3 唯一索引
create table t5(id int,idcard varchar(50),unique index idx2 (idcard)); show create table t5\G insert into t5(id,idcard) values (1,'123'); insert into t5(id,idcard) values (2,'123');
复制
测试记录:
mysql> mysql> create table t5(id int,idcard varchar(50),unique index idx2 (idcard)); Query OK, 0 rows affected (0.03 sec) mysql> show create table t5\G *************************** 1. row *************************** Table: t5 Create Table: CREATE TABLE `t5` ( `id` int DEFAULT NULL, `idcard` varchar(50) DEFAULT NULL, UNIQUE KEY `idx2` (`idcard`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.01 sec) mysql> mysql> insert into t5(id,idcard) values (1,'123'); Query OK, 1 row affected (0.01 sec) mysql> insert into t5(id,idcard) values (2,'123'); ERROR 1062 (23000): Duplicate entry '123' for key 't5.idx2' mysql>
复制
1.4 全文索引
全文索引只适用于 InnoDB、MyISAM存储引擎
也只能创建在CHAR、VARCHAR、TEXT列上
MySQL的全文索引目前而言还不是太适合,有类似需求的基本上的都是elsticsearch数据库。
1.5 多值索引
用于给json列创建索引,应用场景也不多,此处略过。
1.6 空间索引
数据库可以存储地理位置信息,就是空间数据
MySQL存储空间数据不多见,此处略过
1.7 索引相关选项
1.7.1 KEY_BLOCK_SIZE
MyISAM使用,InnoDB存储引擎已不适用
1.7.2 index_type
各个存储引擎支持的索引类型
存储引擎 | 支持的索引类别 |
---|---|
InnoDB | BTREE |
MyISAM | BTREE |
MEMORY/HEAP | HASH, BTREE |
NDB | HASH, BTREE |
1.7.3 COMMENT ‘string’
索引的注释语句
1.7.4 VISIBLE, INVISIBLE
可见和不可见索引
二.删除索引
语法:
DROP INDEX index_name ON tbl_name [algorithm_option | lock_option] ... algorithm_option: ALGORITHM [=] {DEFAULT | INPLACE | COPY} lock_option: LOCK [=] {DEFAULT | NONE | SHARED | EXCLUSIVE}
复制
Oracle 里面,索引和表是同一个命名空间,索引名是不存在重复
MySQL里面不同的表,可以有相同的索引名
show create table t5\G drop index idx2 on t5; create index idx2 on t5(idcard); create table t6(id int,idcard varchar(50),unique index idx2 (idcard)); show create table t6\G
复制
测试记录:
mysql> show create table t5\G *************************** 1. row *************************** Table: t5 Create Table: CREATE TABLE `t5` ( `id` int DEFAULT NULL, `idcard` varchar(50) DEFAULT NULL, UNIQUE KEY `idx2` (`idcard`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.00 sec) mysql> mysql> drop index idx2 on t5; Query OK, 0 rows affected (0.01 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql> mysql> create index idx2 on t5(idcard); Query OK, 0 rows affected (0.02 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql> mysql> create table t6(id int,idcard varchar(50),unique index idx2 (idcard)); Query OK, 0 rows affected (0.06 sec) mysql> mysql> show create table t6\G *************************** 1. row *************************** Table: t6 Create Table: CREATE TABLE `t6` ( `id` int DEFAULT NULL, `idcard` varchar(50) DEFAULT NULL, UNIQUE KEY `idx2` (`idcard`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.00 sec) mysql>
复制
最后修改时间:2020-07-31 10:17:34
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。
文章被以下合辑收录
评论
目录