Skip to content

Commit b95538b

Browse files
authored
best practices: multi-column index optimization (#20955) (#21269)
1 parent 46c6fad commit b95538b

File tree

3 files changed

+268
-0
lines changed

3 files changed

+268
-0
lines changed

TOC.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -422,6 +422,7 @@
422422
- [Use the `tidb_snapshot` System Variable](/read-historical-data.md)
423423
- Best Practices
424424
- [Use TiDB](/best-practices/tidb-best-practices.md)
425+
- [Optimize Multi-Column Indexes](/best-practices/multi-column-index-best-practices.md)
425426
- [Java Application Development](/best-practices/java-app-best-practices.md)
426427
- [Use HAProxy](/best-practices/haproxy-best-practices.md)
427428
- [Highly Concurrent Write](/best-practices/high-concurrency-best-practices.md)
Lines changed: 267 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,267 @@
1+
---
2+
title: Best Practices for Optimizing Multi-Column Indexes
3+
summary: Learn how to use multi-column indexes effectively in TiDB and apply advanced optimization techniques.
4+
---
5+
6+
# Best Practices for Optimizing Multi-Column Indexes
7+
8+
In today's data-driven world, efficiently handling complex queries on large datasets is critical to keeping applications responsive and performant. For TiDB, a distributed SQL database designed to manage high-scale and high-demand environments, optimizing data access paths is essential to delivering smooth and efficient queries.
9+
10+
Indexes are a powerful tool for improving query performance by avoiding the need to scan all rows in a table. TiDB's query optimizer leverages multi-column indexes to intelligently filter data, handling complex query conditions that traditional databases such as MySQL cannot process as effectively.
11+
12+
This document walks you through how multi-column indexes function, why they are crucial, and how TiDB's optimization transforms intricate query conditions into efficient access paths. After optimization, you can achieve faster responses, minimized table scans, and streamlined performance, even at massive scale.
13+
14+
Without these optimizations, query performance in large TiDB databases can degrade quickly. Full table scans and inadequate filtering can turn milliseconds into minutes. Additionally, excessive memory use can lead to out-of-memory (OOM) errors, especially in constrained environments. TiDB's targeted approach ensures only relevant data is accessed. This keeps latency low and memory usage efficient, even for the most complex queries.
15+
16+
## Prerequisites
17+
18+
- The multi-column index feature is available in TiDB v8.3 and later versions.
19+
- Before using this feature, you must set the value of the [optimizer fix control **54337**](/optimizer-fix-controls.md#54337-new-in-v830) to `ON`.
20+
21+
## Background: multi-column indexes
22+
23+
This document takes an example of a rental listings table defined as follows. In this example, each listing contains a unique ID, city, number of bedrooms, rent price, and availability date:
24+
25+
```sql
26+
CREATE TABLE listings (
27+
listing_id INT PRIMARY KEY AUTO_INCREMENT,
28+
city VARCHAR(100) NOT NULL,
29+
bedrooms INT NOT NULL,
30+
price DECIMAL(10, 2) NOT NULL,
31+
availability_date DATE NOT NULL
32+
);
33+
```
34+
35+
Suppose this table has 20 million listings across the United States. If you want to find all listings with a price under $2,000, you can add an index on the price column. This index allows the optimizer to filter out rows, scanning only the range `[-inf, 2000.00)`. This helps reduce the search to about 14 million rows (assuming 70% of rentals are priced above `$2,000`). In the query execution plan, TiDB performs an index range scan on price. This limits the need for a full table scan and improves efficiency.
36+
37+
```sql
38+
-- Query 1: Find listings with price < 2000
39+
EXPLAIN FORMAT = "brief" SELECT * FROM listings WHERE price < 2000;
40+
```
41+
42+
```
43+
+-----------------------------+---------+----------------------------------------------+---------------------------+
44+
| id | task | access object | operator info |
45+
+-----------------------------+---------+----------------------------------------------+---------------------------+
46+
| IndexLookUp | root | | |
47+
| ├─IndexRangeScan(Build) | root | table: listings, index: price_idx(price) | range: [-inf, 2000.00) |
48+
| └─TableRowIDScan(Probe) | root | table: listings | |
49+
+-----------------------------+---------+----------------------------------------------+---------------------------+
50+
```
51+
52+
While this filter improves performance, it might still return a large number of rows. This is not ideal for a user looking for more specific listings. Adding filters, such as specifying the city, number of bedrooms, and a maximum price, narrows the results significantly. For example, a query to find two-bedroom listings in San Francisco under `$2,000` is more useful, likely returning only a few dozen rows.
53+
54+
To optimize this query, you can create a multi-column index on `city`, `bedrooms`, and `price` as follows:
55+
56+
```sql
57+
CREATE INDEX idx_city_bedrooms_price ON listings (city, bedrooms, price);
58+
```
59+
60+
Multi-column indexes in SQL are ordered lexicographically. In the case of an index on `(city, bedrooms, price)`, the data is first sorted by `city`, then by `bedrooms` within each city, and finally by `price` within each `(city, bedrooms)` combination. This ordering lets TiDB efficiently access rows based on each condition:
61+
62+
1. Filter by `city`, which is the primary filter.
63+
2. Optionally filter by `bedrooms` within that city.
64+
3. Optionally filter by `price` within the city-bedroom grouping.
65+
66+
## Sample data
67+
68+
The following table shows a sample dataset that illustrates how multi-column indexing refines search results:
69+
70+
| City | Bedrooms | Price |
71+
| ------------- | -------- | ----- |
72+
| San Diego | 1 | 1000 |
73+
| San Diego | 1 | 1500 |
74+
| San Diego | 2 | 1000 |
75+
| San Diego | 2 | 2500 |
76+
| San Diego | 3 | 1000 |
77+
| San Diego | 3 | 2500 |
78+
| San Francisco | 1 | 1000 |
79+
| San Francisco | 1 | 1500 |
80+
| San Francisco | 2 | 1000 |
81+
| San Francisco | 2 | 1500 |
82+
| San Francisco | 3 | 2500 |
83+
| San Francisco | 3 | 3000 |
84+
85+
## Optimized queries and results
86+
87+
Using the multi-column index, TiDB can efficiently narrow the scan range to find listings in San Francisco with two bedrooms and a price under $2,000:
88+
89+
```sql
90+
-- Query 2: Find two-bedroom listings in San Francisco under $2,000
91+
EXPLAIN FORMAT = "brief"
92+
SELECT * FROM listings
93+
WHERE city = 'San Francisco' AND bedrooms = 2 AND price < 2000;
94+
```
95+
96+
```
97+
+------------------------+------+---------------------------------------------------------------------------------------------+---------------------------------+
98+
| id | task | access object | operator info |
99+
+------------------------+------+---------------------------------------------------------------------------------------------+---------------------------------+
100+
| IndexLookUp | root | | |
101+
| ├─IndexRangeScan(Build)| root |table:listings,index:idx_city_bedrooms_price ["San Francisco" 2 -inf,(city, bedrooms, price)]|range:["San Francisco" 2 2000.00)|
102+
| └─TableRowIDScan(Probe)| root |table:listings | |
103+
+------------------------+------+---------------------------------------------------------------------------------------------+---------------------------------+
104+
```
105+
106+
This query returns the following filtered results from the sample data:
107+
108+
| City | Bedrooms | Price |
109+
|---------------|----------|-------|
110+
| San Francisco | 2 | 1000 |
111+
| San Francisco | 2 | 1500 |
112+
113+
By using a multi-column index, TiDB avoids unnecessary row scanning and significantly boosts query performance.
114+
115+
## Index range derivation
116+
117+
The TiDB optimizer includes a powerful range derivation component. It is designed to take a query's conditions and relevant index columns and generate efficient index ranges for table access. This derived range then feeds into TiDB's table access component, which determines the most resource-efficient way to access the table.
118+
119+
For each table in a query, the table access component evaluates all applicable indexes to identify the optimal access method—whether through a full table scan or an index scan. It calculates the range for each relevant index, assesses the access cost, and selects the path with the lowest cost. This process combines range derivation with a cost assessment subsystem to find the most efficient way to retrieve data, balancing performance and resource usage.
120+
121+
The diagram below illustrates how the range derivation and cost assessment work together within TiDB's table access logic to achieve optimal data retrieval.
122+
123+
![Table Access Path Selection](/media/best-practices/multi-column-index-table-access-path-selection.png)
124+
125+
Multi-column filters are often more complex than the basic examples discussed earlier. They might include **AND** conditions, **OR** conditions, or a combination of both. TiDB's range derivation subsystem is designed to handle these cases efficiently, generating the most selective (and therefore, most effective) index ranges.
126+
127+
In general, the subsystem applies a **UNION** operation for ranges generated from **OR** conditions and an **INTERSECT** operation for ranges derived from **AND** conditions. This approach ensures that TiDB can filter data as precisely as possible, even with complex filtering logic.
128+
129+
## Disjunctive conditions (`OR` conditions) in multi-column indexes
130+
131+
When there are `OR` conditions in a query (known as "disjunctive predicates"), the optimizer handles each condition separately, creating a range for each part of the `OR` condition. If any of these ranges overlap, the optimizer merges them into one continuous range. If they do not overlap, they remain as separate ranges, both of which can still be used for an index scan.
132+
133+
### Example 1: overlapping ranges
134+
135+
Consider a query that looks for listings in New York with two bedrooms, where the price falls into one of two overlapping ranges:
136+
137+
- Price between `$1,000` and `$2,000`
138+
- Price between `$1,500` and `$2,500`
139+
140+
In this case, the two ranges overlap, so the optimizer combines them into a single range from `$1,000` to `$2,500`. Here is the query and its execution plan:
141+
142+
```sql
143+
-- Query 3: Overlapping price ranges
144+
EXPLAIN FORMAT = "brief"
145+
SELECT * FROM listings
146+
WHERE (city = 'New York' AND bedrooms = 2 AND price >= 1000 AND price < 2000)
147+
OR (city = 'New York' AND bedrooms = 2 AND price >= 1500 AND price < 2500);
148+
```
149+
150+
```
151+
+-------------------------+------+----------------------------------------------------------------------+--------------------------------------------------+
152+
| id | task | access object | operator info |
153+
+-------------------------+------+----------------------------------------------------------------------+--------------------------------------------------+
154+
| IndexLookUp | root | | |
155+
| ├─IndexRangeScan(Build) | root | table:listings,index:idx_city_bedrooms_price(city, bedrooms, price) | range:["New York" 2 1000.00,"New York" 2 2500.00)|
156+
| └─TableRowIDScan(Probe) | root | table:listings | |
157+
+-------------------------+------+----------------------------------------------------------------------+--------------------------------------------------+
158+
```
159+
160+
### Example 2: non-overlapping ranges
161+
162+
In a different scenario, imagine a query that looks for affordable single-bedroom listings in either San Francisco or San Diego. Here, the `OR` condition specifies two distinct ranges for different cities:
163+
164+
- Listings in San Francisco, 1 bedroom, priced between `$1,500` and `$2,500`
165+
- Listings in San Diego, 1 bedroom, priced between `$1,000` and `$1,500`
166+
167+
Because the index ranges do not overlap, they remain separate in the execution plan, with each city having its own index range:
168+
169+
```sql
170+
-- Query 4: Non-overlapping ranges for different cities
171+
172+
EXPLAIN FORMAT = "brief"
173+
SELECT * FROM listings
174+
WHERE
175+
(city = 'San Francisco' AND bedrooms = 1 AND price >= 1500 AND price < 2500)
176+
OR (city = 'San Diego' AND bedrooms = 1 AND price >= 1000 AND price < 1500);
177+
```
178+
179+
```
180+
+-------------------------+------+--------------------------------------------------------------------+------------------------------------------------------------+
181+
| id | task | access object | operator info |
182+
+-------------------------+------+--------------------------------------------------------------------+------------------------------------------------------------+
183+
| IndexLookUp | root | | |
184+
| ├─IndexRangeScan(Build) | root | table:listings,index:idx_city_bedrooms_price(city, bedrooms, price)| range:["San Francisco" 1 1500.00,"San Francisco" 1 2500.00)|
185+
| └─TableRowIDScan(Probe) | root | table:listings | ["San Diego" 1 1000.00,"San Diego" 1 1500.00) |
186+
+-------------------------+------+--------------------------------------------------------------------+------------------------------------------------------------+
187+
```
188+
189+
By creating either merged or distinct ranges based on overlap, the optimizer can efficiently use indexes for `OR` conditions, avoiding unnecessary scans and improving query performance.
190+
191+
## Conjunctive conditions (`AND` conditions) in multi-column indexes
192+
193+
For queries with **AND** conditions (also known as conjunctive conditions), the TiDB optimizer creates a range for each condition. It then finds the overlap (intersection) of these ranges to get a precise result for index access. If each condition has only one range, this is straightforward, but it becomes more complex if any condition contains multiple ranges. In such cases, TiDB combines these ranges to produce the most selective, efficient result.
194+
195+
### Example 1: table setup
196+
197+
Consider a table `t1` that is defined as follows:
198+
199+
```sql
200+
CREATE TABLE t1 (
201+
a1 INT,
202+
b1 INT,
203+
c1 INT,
204+
KEY iab (a1,b1)
205+
);
206+
```
207+
208+
Suppose you have a query with the following conditions:
209+
210+
```sql
211+
(a1, b1) > (1, 10) AND (a1, b1) < (10, 20)
212+
```
213+
214+
This query involves comparing multiple columns, and requires the TiDB optimizer to process it in the following two steps:
215+
216+
1. Translate the expressions.
217+
218+
The TiDB optimizer breaks down these complex conditions into simpler parts.
219+
220+
- `(a1, b1) > (1, 10)` translates to `(a1 > 1) OR (a1 = 1 AND b1 > 10)`, meaning it includes all cases where `a1` is greater than `1` or where `a1` is exactly `1` and `b1` is greater than `10`.
221+
- `(a1, b1) < (10, 20)` translates to `(a1 < 10) OR (a1 = 10 AND b1 < 20)`, covering cases where `a1` is less than `10` or where `a1` is exactly `10` and `b1` is less than `20`.
222+
223+
These expressions are then combined using `AND`:
224+
225+
```sql
226+
((a1 > 1) OR (a1 = 1 AND b1 > 10)) AND ((a1 < 10) OR (a1 = 10 AND b1 < 20))
227+
```
228+
229+
2. Derive and combine ranges.
230+
231+
After breaking down the conditions, the TiDB optimizer calculates ranges for each part and combines them. For this example, it derives:
232+
233+
- For `(a1, b1) > (1, 10)`: it creates ranges such as `(1, +inf]` for cases where `a1 > 1` and `(1, 10, 1, +inf]` for cases where `a1 = 1` and `b1 > 10`.
234+
- For `(a1, b1) < (10, 20)`: it creates ranges `[-inf, 10)` for cases where `a1 < 10` and `[10, -inf, 10, 20)` for cases where `a1 = 10` and `b1 < 20`.
235+
236+
The final result combines these to get a refined range: `(1, 10, 1, +inf] UNION (1, 10) UNION [10, -inf, 10, 20)`.
237+
238+
### Example 2: query plan
239+
240+
The following query plan shows the derived ranges:
241+
242+
```sql
243+
-- Query 5: Conjunctive conditions on (a1, b1)
244+
EXPLAIN FORMAT = "brief"
245+
SELECT * FROM t1
246+
WHERE (a1, b1) > (1, 10) AND (a1, b1) < (10, 20);
247+
```
248+
249+
```
250+
+-------------------------+------+----------------------------+-------------------------------------------+
251+
| id | task | access object | operator info |
252+
+-------------------------+------+----------------------------+-------------------------------------------+
253+
| IndexLookUp | root | | |
254+
| ├─IndexRangeScan(Build) | root | table:t1,index:iab(a1, b1) | range:(1 10,1 +inf],(1,10)[10 -inf,10 20) |
255+
| └─TableRowIDScan(Probe) | root | table:t1 | |
256+
+-------------------------+------+----------------------------+-------------------------------------------+
257+
```
258+
259+
In this example, the table has about 500 million rows. However, this optimization allows TiDB to narrow down the access to only around 4,000 rows, just 0.0008% of the total data. This refinement drastically reduces query latency to a few milliseconds, as opposed to over two minutes without optimization.
260+
261+
Unlike MySQL, which requires a full table scan for such conditions, the TiDB optimizer can handle complex row expressions efficiently by leveraging these derived ranges.
262+
263+
## Conclusion
264+
265+
The TiDB optimizer uses multi-column indexes and advanced range derivation to significantly lower data access costs for complex SQL queries. By effectively managing both conjunctive (`AND`) and disjunctive (`OR`) conditions, TiDB converts row-based expressions into optimal access paths, reducing query times and enhancing performance. Unlike MySQL, TiDB supports union and intersection operations on multi-column indexes, allowing efficient processing of intricate filters. In practical use, this optimization enables TiDB to complete queries in just a few milliseconds—compared to over two minutes without it, demonstrating a substantial reduction in latency.
266+
267+
Check out the [comparison white paper](https://www.pingcap.com/ebook-whitepaper/tidb-vs-mysql-product-comparison-guide/) to discover even more differences between MySQL and TiDB's architecture, and why this matters for scalability, reliability, and hybrid transactional and analytical workloads.
Loading

0 commit comments

Comments
 (0)