Skip to content

Commit ca4faf7

Browse files
committed
index: add document for partial index
Signed-off-by: Yang Keao <[email protected]>
1 parent 3958dbe commit ca4faf7

File tree

1 file changed

+133
-0
lines changed

1 file changed

+133
-0
lines changed

sql-statements/sql-statement-create-index.md

Lines changed: 133 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -45,6 +45,7 @@ IndexOption ::=
4545
| 'COMMENT' stringLit
4646
| ("VISIBLE" | "INVISIBLE")
4747
| ("GLOBAL" | "LOCAL")
48+
| 'WHERE' Expression
4849
4950
IndexTypeName ::=
5051
'BTREE'
@@ -383,6 +384,138 @@ Query OK, 1 row affected (0.00 sec)
383384
- 使用备份恢复工具 (BR)、同步工具 (TiCDC)、导入工具 (TiDB Lightning) 无法将定义了多值索引的表备份、同步、导入到低于 v6.6.0 版本的 TiDB。
384385
- 条件复杂的查询有可能无法选择到多值索引,多值索引支持的条件模式请参考[使用多值索引](/choose-index.md#使用多值索引)。
385386
387+
## 部分索引
388+
389+
部分索引是在表中行的子集上构建的索引,由条件表达式(称为部分索引的谓词)定义。该索引仅包含满足谓词的行的条目。
390+
391+
### 创建部分索引
392+
393+
你可以通过在索引定义中添加 `WHERE` 子句来创建部分索引。例如:
394+
395+
```sql
396+
CREATE TABLE t1 (c1 INT, c2 INT, c3 STRING);
397+
CREATE INDEX idx1 ON t1 (c1) WHERE c2 > 10;
398+
```
399+
400+
你也可以使用 `ALTER TABLE` 来创建部分索引:
401+
402+
```sql
403+
ALTER TABLE t1 ADD INDEX idx2 (c1, c2) WHERE c3 = 'abc';
404+
```
405+
406+
或者在创建表时指定部分索引:
407+
408+
```sql
409+
CREATE TABLE t2 (
410+
id INT PRIMARY KEY,
411+
status VARCHAR(20),
412+
created_at DATETIME,
413+
INDEX idx_active_status (status) WHERE status = 'active'
414+
);
415+
```
416+
417+
### 使用示例
418+
419+
以下示例演示如何有效地使用部分索引:
420+
421+
```sql
422+
-- 创建包含用户数据的表
423+
CREATE TABLE users (
424+
id INT PRIMARY KEY AUTO_INCREMENT,
425+
name VARCHAR(100),
426+
status varchar(20),
427+
created_at DATETIME,
428+
score INT
429+
);
430+
431+
-- 为常见查询模式创建部分索引
432+
CREATE INDEX idx_active_users ON users (name) WHERE status = 'active';
433+
CREATE INDEX idx_high_score_users ON users (created_at) WHERE score > 1000;
434+
CREATE INDEX idx_pending_status ON users (created_at) WHERE status = 'pending';
435+
```
436+
437+
然后以下查询可以使用部分索引:
438+
439+
```
440+
mysql> explain SELECT * FROM users WHERE status = 'active' AND name = 'John';
441+
+-------------------------------+---------+-----------+-------------------------------------------+-------------------------------------------------------+
442+
| id | estRows | task | access object | operator info |
443+
+-------------------------------+---------+-----------+-------------------------------------------+-------------------------------------------------------+
444+
| IndexLookUp_9 | 1.00 | root | | |
445+
| ├─IndexRangeScan_6(Build) | 10.00 | cop[tikv] | table:users, index:idx_active_users(name) | range:["John","John"], keep order:false, stats:pseudo |
446+
| └─Selection_8(Probe) | 1.00 | cop[tikv] | | eq(test.users.status, "active") |
447+
| └─TableRowIDScan_7 | 10.00 | cop[tikv] | table:users | keep order:false, stats:pseudo |
448+
+-------------------------------+---------+-----------+-------------------------------------------+-------------------------------------------------------+
449+
4 rows in set (0.00 sec)
450+
451+
mysql> explain SELECT * FROM users WHERE status = 'active' ORDER BY name;
452+
+-------------------------------+----------+-----------+-------------------------------------------+---------------------------------+
453+
| id | estRows | task | access object | operator info |
454+
+-------------------------------+----------+-----------+-------------------------------------------+---------------------------------+
455+
| IndexLookUp_18 | 10.00 | root | | |
456+
| ├─IndexFullScan_15(Build) | 10000.00 | cop[tikv] | table:users, index:idx_active_users(name) | keep order:true, stats:pseudo |
457+
| └─Selection_17(Probe) | 10.00 | cop[tikv] | | eq(test.users.status, "active") |
458+
| └─TableRowIDScan_16 | 10000.00 | cop[tikv] | table:users | keep order:false, stats:pseudo |
459+
+-------------------------------+----------+-----------+-------------------------------------------+---------------------------------+
460+
4 rows in set (0.00 sec)
461+
462+
mysql> explain SELECT * FROM users WHERE score > 10000 ORDER BY created_at;
463+
+-------------------------------+----------+-----------+-----------------------------------------------------+--------------------------------+
464+
| id | estRows | task | access object | operator info |
465+
+-------------------------------+----------+-----------+-----------------------------------------------------+--------------------------------+
466+
| IndexLookUp_18 | 3333.33 | root | | |
467+
| ├─IndexFullScan_15(Build) | 10000.00 | cop[tikv] | table:users, index:idx_high_score_users(created_at) | keep order:true, stats:pseudo |
468+
| └─Selection_17(Probe) | 3333.33 | cop[tikv] | | gt(test.users.score, 10000) |
469+
| └─TableRowIDScan_16 | 10000.00 | cop[tikv] | table:users | keep order:false, stats:pseudo |
470+
+-------------------------------+----------+-----------+-----------------------------------------------------+--------------------------------+
471+
4 rows in set (0.00 sec)
472+
473+
mysql> explain SELECT * FROM users WHERE status = 'pending';
474+
+-------------------------+----------+-----------+---------------+----------------------------------+
475+
| id | estRows | task | access object | operator info |
476+
+-------------------------+----------+-----------+---------------+----------------------------------+
477+
| TableReader_8 | 10.00 | root | | data:Selection_7 |
478+
| └─Selection_7 | 10.00 | cop[tikv] | | eq(test.users.status, "pending") |
479+
| └─TableFullScan_6 | 10000.00 | cop[tikv] | table:users | keep order:false, stats:pseudo |
480+
+-------------------------+----------+-----------+---------------+----------------------------------+
481+
3 rows in set (0.00 sec)
482+
```
483+
484+
如果查询中的谓词不满足索引定义,即使使用 hint 也不会选择该索引:
485+
486+
```
487+
mysql> explain SELECT * FROM users use index(idx_high_score_users) WHERE score > 100 ORDER BY created_at;
488+
+---------------------------+----------+-----------+---------------+--------------------------------+
489+
| id | estRows | task | access object | operator info |
490+
+---------------------------+----------+-----------+---------------+--------------------------------+
491+
| Sort_5 | 3333.33 | root | | test.users.created_at |
492+
| └─TableReader_11 | 3333.33 | root | | data:Selection_10 |
493+
| └─Selection_10 | 3333.33 | cop[tikv] | | gt(test.users.score, 100) |
494+
| └─TableFullScan_9 | 10000.00 | cop[tikv] | table:users | keep order:false, stats:pseudo |
495+
+---------------------------+----------+-----------+---------------+--------------------------------+
496+
```
497+
498+
### 何时使用部分索引
499+
500+
部分索引在以下场景中特别有用:
501+
502+
- **选择性过滤**:当你经常基于特定条件查询一小部分行时
503+
- **条件唯一性**:当你需要只在某些条件下应用唯一约束时
504+
505+
### 限制
506+
507+
- 部分索引的 `WHERE` 子句支持基本比较运算符(`=`、`!=`、`<`、`<=`、`>`、`>=`)和具有常量值的 `IN` 谓词
508+
- 列和常量值的类型应该相同
509+
- 谓词只能引用同一表中的列
510+
- 部分索引不能用于表达式索引
511+
512+
### 性能优势
513+
514+
部分索引提供几个优势:
515+
516+
1. **减少存储**:只有匹配谓词的行被索引,节省存储空间
517+
2. **更快的 DML**:在 INSERT、UPDATE 和 DELETE 操作期间维护数据子集的索引会更快
518+
386519
## 不可见索引
387520
388521
默认情况下,不可见索引 (Invisible Indexes) 不会被查询优化器使用:

0 commit comments

Comments
 (0)