Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

SQL statement, system variables: update expression indexes #6185

88 changes: 77 additions & 11 deletions sql-statements/sql-statement-create-index.md
Original file line number Diff line number Diff line change
Expand Up @@ -104,44 +104,108 @@ Query OK, 0 rows affected (0.31 sec)

## Expression index

In some scenarios, query conditions run a filtering process based on a certain expression. In this case, the query performance is relatively poor because general indexes can not take effect in those scenarios, so the query can only be completed by traversing the entire table. Expression indexes are the special index that can be built on an expression. Once an expression index is built, you can use the index for the expression-based query, which significantly speeds up the query performance.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

If you want to build the indexes based on `col1+cols2`, run the following SQL statement as an example:
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

{{< copyable "sql" >}}

```sql
CREATE INDEX idx1 ON t1 ((col1 + col2));
```

Or you can run the following alternative statement:
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

{{< copyable "sql" >}}

```sql
ALTER TABLE t1 ADD INDEX idx1((col1 + col2));
```

You can also specify the expression index as you build the table:
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

{{< copyable "sql" >}}

```sql
CREATE TABLE t1(col1 char(10), col2 char(10), key index((col1 + col2)));
```

The method of deleting an expression index is the same as that of deleting a general index:
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

{{< copyable "sql" >}}

```sql
DROP INDEX idx1 ON t1;
```

> **Note:**
>
> Expression index is still an experimental feature. It is **NOT** recommended that you use it in the production environment.
> An expression index can not be a primary key.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved
>
> An expression with expression indexes can not contain the following:
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved
>
> - volatile functions, such as `rand()`, `now()`, and so on.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved
> - system variables and user variables.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved
> - a subquery.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved
> - `AUTO_INCREMENT` column. However, there is one exception: you can remove this restriction by setting the value of `tidb_enable_auto_increment_in_generated` (system variable) to `true`.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved
> - window functions.
> - the ROW functions, such as `create table t (j json, key k (((j,j))));`.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved
> - aggregate functions.
>
> An expression index takes names implicitly by setting `_V$_{index_name}_{index_offset}`. Suppose you try to set a new expression index's name that a column has taken when creating an expression index. In that case, an error returns in this process. Besides, if you add a column with an existing name, the same error returns.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved
>
> The number of parameters of the functions that are in an expression with expression indexes must be correct.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

To use this feature, make the following setting in [TiDB Configuration File](/tidb-configuration-file.md#allow-expression-index-new-in-v400):
When the expression in a query statement matches the expression in an expression index, the optimizer can choose to use the expression index for the query. In some cases, the optimizer may not select an expression index depending on statistics. At that time, you can force the optimizer to select an expression index by specifying optimizer hints.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

For example, suppose you build the expression index `idx` on the expression `lower(col1)`:
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

If the results of the query statement are the same expressions, you can use expression indexes. Take the following statements as an example:
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

{{< copyable "sql" >}}

```sql
allow-expression-index = true
SELECT lower(col1) FROM t;
```

TiDB can build indexes not only on one or more columns in a table, but also on an expression. When queries involve expressions, expression indexes can speed up those queries.
If the same expressions are included in the filtering conditions, you can use expression indexes. Take the following statements as an example:
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

Take the following query as an example:
{{< copyable "sql" >}}

```sql
SELECT * FROM t WHERE lower(col1) = "a";
SELECT * FROM t WHERE lower(col1) > "a";
SELECT * FROM t WHERE lower(col1) BETWEEN "a" AND "b";
SELECT * FROM t WHERE lower(col1) in ("a", "b");
SELECT * FROM t WHERE lower(col1) > "a" AND lower(col1) < "b";
SELECT * FROM t WHERE lower(col1) > "b" OR lower(col1) < "a";
```

When the queries are sorted by the same expressions, you can use expression indexes. Take the following statements as an example:
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

{{< copyable "sql" >}}

```sql
SELECT * FROM t WHERE lower(name) = "pingcap";
SELECT * FROM t ORDER BY lower(col1);
```

If the following expression index is built, you can use the index to speed up the above query:
If the same expressions are included in the aggregate (`GROUP BY`) functions, you can use expression indexes. Take the following statements as an example:
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

{{< copyable "sql" >}}

```sql
CREATE INDEX idx ON t ((lower(name)));
SELECT max(lower(col1)) FROM t;
SELECT min(col1) FROM t GROUP BY lower(col1);
```

To see the expression corresponding to the expression index, run `show index`, or check the system table `information_schema.tidb_indexes` and the table `information_schema.STATISTICS`. The Expression in the output indicates the corresponded expression. As for the indexes that are not expression indexes, the column shows `NULL`.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

The cost of maintaining an expression index is higher than that of maintaining other indexes, because the value of the expression needs to be calculated whenever a row is inserted or updated. The value of the expression is already stored in the index, so this value does not require recalculation when the optimizer selects the expression index.

Therefore, when the query performance outweighs the insert and update performance, you can consider indexing the expressions.

Expression indexes have the same syntax and limitations as in MySQL. They are implemented by building indexes on generated virtual columns that are invisible, so the supported expressions inherit all [limitations of virtual generated columns](/generated-columns.md#limitations).
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

Currently, the optimizer can use the indexed expressions when the expressions are only in the `FIELD` clause, `WHERE` clause, and `ORDER BY` clause. The `GROUP BY` clause will be supported in future updates.

## Invisible index

Invisible indexes are indexes that are ignored by the query optimizer:
Expand All @@ -155,13 +219,15 @@ For details, see [`ALTER INDEX`](/sql-statements/sql-statement-alter-index.md).

## Associated session variables

The global variables associated with the `CREATE INDEX` statement are `tidb_ddl_reorg_worker_cnt`, `tidb_ddl_reorg_batch_size` and `tidb_ddl_reorg_priority`. Refer to [system variables](/system-variables.md#tidb_ddl_reorg_worker_cnt) for details.
The global variables associated with the `CREATE INDEX` statement are `tidb_ddl_reorg_worker_cnt`, `tidb_ddl_reorg_batch_size`, `tidb_ddl_reorg_priority`, and `tidb_enable_auto_increment_in_generated`. Refer to [system variables](/system-variables.md#tidb_ddl_reorg_worker_cnt) for details.

## MySQL compatibility

* `FULLTEXT`, `HASH` and `SPATIAL` indexes are not supported.
* Descending indexes are not supported (similar to MySQL 5.7).
* Adding the primary key of the `CLUSTERED` type to a table is not supported. For more details about the primary key of the `CLUSTERED` type, refer to [clustered index](/clustered-indexes.md).
* Expression indexes are incompatible with views. When you query contents by using views, the expression index can not be used at the same time.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved
* There are compatibility issues between expression indexes and bindings. When an expression in an expression index has constants, the binding created for the corresponding query expands its scope. For example, suppose the expression in the expression index is `a+1`, and the corresponding query condition is `a+1 > 2`. In this case, the binding is `a+? > ?`, which means that the queries such as `a+2 > 2` are also forced to use the expression index. It results in a poor execution plan. Besides, this also affects the baseline capturing and baseline evolution belonging to SQL Plan Management.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

## See also

Expand Down
6 changes: 6 additions & 0 deletions system-variables.md
Original file line number Diff line number Diff line change
Expand Up @@ -501,6 +501,12 @@ Constraint checking is always performed in place for pessimistic transactions (d
> - If you have enabled TiDB Binlog, enabling this variable cannot improve the performance. To improve the performance, it is recommended to use [TiCDC](/ticdc/ticdc-overview.md) instead.
> - Enabling this parameter only means that Async Commit becomes an optional mode of transaction commit. In fact, the most suitable mode of transaction commit is determined by TiDB.

### tidb_enable_auto_increment_in_generated

- Scope: SESSION | GLOBAL
- Default value: `OFF`
- This variable is used to determine whether can include the `AUTO_INCREMENT` columns when creating a generated column or an expression index.
en-jin19 marked this conversation as resolved.
Show resolved Hide resolved

### tidb_enable_cascades_planner

- Scope: SESSION | GLOBAL
Expand Down
11 changes: 1 addition & 10 deletions tidb-configuration-file.md
Original file line number Diff line number Diff line change
Expand Up @@ -636,13 +636,4 @@ For pessimistic transaction usage, refer to [TiDB Pessimistic Transaction Mode](
+ The maximum number of deadlock events that can be recorded in the [`INFORMATION_SCHEMA.DEADLOCKS`](/information-schema/information-schema-deadlocks.md) table of a single TiDB server. If this table is in full volume and an additional deadlock event occurs, the earliest record in the table will be removed to make place for the newest error.
+ Default value: `10`
+ Minimum value: `0`
+ Maximum value: `10000`

## experimental

The `experimental` section, introduced in v3.1.0, describes configurations related to the experimental features of TiDB.

### `allow-expression-index` <span class="version-mark">New in v4.0.0</span>

- Determines whether to create the expression index.
- Default value: `false`
+ Maximum value: `10000`