Skip to content

Commit 355e3e4

Browse files
committed
add docs for partial index
Signed-off-by: Yang Keao <[email protected]>
1 parent cce9ab3 commit 355e3e4

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
@@ -53,6 +53,7 @@ IndexOption ::=
5353
| 'COMMENT' stringLit
5454
| ("VISIBLE" | "INVISIBLE")
5555
| ("GLOBAL" | "LOCAL")
56+
| 'WHERE' Expression
5657
5758
IndexTypeName ::=
5859
'BTREE'
@@ -366,6 +367,138 @@ See [Index Selection - Use multi-valued indexes](/choose-index.md#use-multi-valu
366367
- If a table uses multi-valued indexes, you cannot back up, replicate, or import the table using BR, TiCDC, or TiDB Lightning to a TiDB cluster earlier than v6.6.0.
367368
- For a query with complex conditions, TiDB might not be able to select multi-valued indexes. For information on the condition patterns supported by multi-valued indexes, refer to [Use multi-valued indexes](/choose-index.md#use-multi-valued-indexes).
368369
370+
## Partial indexes
371+
372+
A partial index is an index built on a subset of rows in a table, defined by a conditional expression (called the predicate of the partial index). The index contains entries only for those rows that satisfy the predicate.
373+
374+
### Create partial indexes
375+
376+
You can create partial indexes by adding a `WHERE` clause to the index definition. For example:
377+
378+
```sql
379+
CREATE TABLE t1 (c1 INT, c2 INT, c3 TEXT);
380+
CREATE INDEX idx1 ON t1 (c1) WHERE c2 > 10;
381+
```
382+
383+
You can also create partial indexes using `ALTER TABLE`:
384+
385+
```sql
386+
ALTER TABLE t1 ADD INDEX idx2 (c1, c2) WHERE c3 = 'abc';
387+
```
388+
389+
Or specify the partial index when creating the table:
390+
391+
```sql
392+
CREATE TABLE t2 (
393+
id INT PRIMARY KEY,
394+
status VARCHAR(20),
395+
created_at DATETIME,
396+
INDEX idx_active_status (status) WHERE status = 'active'
397+
);
398+
```
399+
400+
### Usage examples
401+
402+
The following examples demonstrate how to use partial indexes effectively:
403+
404+
```sql
405+
-- Create a table with user data
406+
CREATE TABLE users (
407+
id INT PRIMARY KEY AUTO_INCREMENT,
408+
name VARCHAR(100),
409+
status varchar(20),
410+
created_at DATETIME,
411+
score INT
412+
);
413+
414+
-- Create partial indexes for common query patterns
415+
CREATE INDEX idx_active_users ON users (name) WHERE status = 'active';
416+
CREATE INDEX idx_high_score_users ON users (created_at) WHERE score > 1000;
417+
CREATE INDEX idx_pending_status ON users (created_at) WHERE status = 'pending';
418+
```
419+
420+
Then the following queries can use the partial index:
421+
422+
```
423+
mysql> explain SELECT * FROM users WHERE status = 'active' AND name = 'John';
424+
+-------------------------------+---------+-----------+-------------------------------------------+-------------------------------------------------------+
425+
| id | estRows | task | access object | operator info |
426+
+-------------------------------+---------+-----------+-------------------------------------------+-------------------------------------------------------+
427+
| IndexLookUp_9 | 1.00 | root | | |
428+
| ├─IndexRangeScan_6(Build) | 10.00 | cop[tikv] | table:users, index:idx_active_users(name) | range:["John","John"], keep order:false, stats:pseudo |
429+
| └─Selection_8(Probe) | 1.00 | cop[tikv] | | eq(test.users.status, "active") |
430+
| └─TableRowIDScan_7 | 10.00 | cop[tikv] | table:users | keep order:false, stats:pseudo |
431+
+-------------------------------+---------+-----------+-------------------------------------------+-------------------------------------------------------+
432+
4 rows in set (0.00 sec)
433+
434+
mysql> explain SELECT * FROM users WHERE status = 'active' ORDER BY name;
435+
+-------------------------------+----------+-----------+-------------------------------------------+---------------------------------+
436+
| id | estRows | task | access object | operator info |
437+
+-------------------------------+----------+-----------+-------------------------------------------+---------------------------------+
438+
| IndexLookUp_18 | 10.00 | root | | |
439+
| ├─IndexFullScan_15(Build) | 10000.00 | cop[tikv] | table:users, index:idx_active_users(name) | keep order:true, stats:pseudo |
440+
| └─Selection_17(Probe) | 10.00 | cop[tikv] | | eq(test.users.status, "active") |
441+
| └─TableRowIDScan_16 | 10000.00 | cop[tikv] | table:users | keep order:false, stats:pseudo |
442+
+-------------------------------+----------+-----------+-------------------------------------------+---------------------------------+
443+
4 rows in set (0.00 sec)
444+
445+
mysql> explain SELECT * FROM users WHERE score > 10000 ORDER BY created_at;
446+
+-------------------------------+----------+-----------+-----------------------------------------------------+--------------------------------+
447+
| id | estRows | task | access object | operator info |
448+
+-------------------------------+----------+-----------+-----------------------------------------------------+--------------------------------+
449+
| IndexLookUp_18 | 3333.33 | root | | |
450+
| ├─IndexFullScan_15(Build) | 10000.00 | cop[tikv] | table:users, index:idx_high_score_users(created_at) | keep order:true, stats:pseudo |
451+
| └─Selection_17(Probe) | 3333.33 | cop[tikv] | | gt(test.users.score, 10000) |
452+
| └─TableRowIDScan_16 | 10000.00 | cop[tikv] | table:users | keep order:false, stats:pseudo |
453+
+-------------------------------+----------+-----------+-----------------------------------------------------+--------------------------------+
454+
4 rows in set (0.00 sec)
455+
456+
mysql> explain SELECT * FROM users WHERE status = 'pending';
457+
+-------------------------+----------+-----------+---------------+----------------------------------+
458+
| id | estRows | task | access object | operator info |
459+
+-------------------------+----------+-----------+---------------+----------------------------------+
460+
| TableReader_8 | 10.00 | root | | data:Selection_7 |
461+
| └─Selection_7 | 10.00 | cop[tikv] | | eq(test.users.status, "pending") |
462+
| └─TableFullScan_6 | 10000.00 | cop[tikv] | table:users | keep order:false, stats:pseudo |
463+
+-------------------------+----------+-----------+---------------+----------------------------------+
464+
3 rows in set (0.00 sec)
465+
```
466+
467+
If the predicates in query don't meet the index definition, the index will not be chosen even with hint:
468+
469+
```
470+
mysql> explain SELECT * FROM users use index(idx_high_score_users) WHERE score > 100 ORDER BY created_at;
471+
+---------------------------+----------+-----------+---------------+--------------------------------+
472+
| id | estRows | task | access object | operator info |
473+
+---------------------------+----------+-----------+---------------+--------------------------------+
474+
| Sort_5 | 3333.33 | root | | test.users.created_at |
475+
| └─TableReader_11 | 3333.33 | root | | data:Selection_10 |
476+
| └─Selection_10 | 3333.33 | cop[tikv] | | gt(test.users.score, 100) |
477+
| └─TableFullScan_9 | 10000.00 | cop[tikv] | table:users | keep order:false, stats:pseudo |
478+
+---------------------------+----------+-----------+---------------+--------------------------------+
479+
```
480+
481+
### When to use partial indexes
482+
483+
Partial indexes are particularly useful in the following scenarios:
484+
485+
- **Selective filtering**: When you frequently query a small subset of rows based on specific conditions
486+
- **Conditional uniqueness**: When you need unique constraints that only apply under certain conditions
487+
488+
### Limitations
489+
490+
- The `WHERE` clause in partial indexes supports basic comparison operators (`=`, `!=`, `<`, `<=`, `>`, `>=`) and `IN` predicates with constant values
491+
- The types of the column and constant value should be the same
492+
- The predicate can only reference columns from the same table
493+
- Partial indexes cannot be used on expression indexes
494+
495+
### Performance benefits
496+
497+
Partial indexes offer several advantages:
498+
499+
1. **Reduced storage**: Only rows matching the predicate are indexed, saving storage space
500+
2. **Faster DML**: It'll be faster to maintain the index of a subset of data during INSERT, UPDATE, and DELETE operations
501+
369502
## Invisible index
370503
371504
By default, invisible indexes are indexes that are ignored by the query optimizer:

0 commit comments

Comments
 (0)