You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
Copy file name to clipboardExpand all lines: sql-statements/sql-statement-create-index.md
+133Lines changed: 133 additions & 0 deletions
Display the source diff
Display the rich diff
Original file line number
Diff line number
Diff line change
@@ -53,6 +53,7 @@ IndexOption ::=
53
53
| 'COMMENT' stringLit
54
54
| ("VISIBLE" | "INVISIBLE")
55
55
| ("GLOBAL" | "LOCAL")
56
+
| 'WHERE' Expression
56
57
57
58
IndexTypeName ::=
58
59
'BTREE'
@@ -366,6 +367,138 @@ See [Index Selection - Use multi-valued indexes](/choose-index.md#use-multi-valu
366
367
- 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.
367
368
- 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).
368
369
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';
0 commit comments