Skip to content
67 changes: 67 additions & 0 deletions functions-and-operators/tidb-functions.md
Original file line number Diff line number Diff line change
Expand Up @@ -17,6 +17,7 @@ The following functions are TiDB extensions, and are not present in MySQL:
| [`TIDB_VERSION()`](#tidb_version) | The `TIDB_VERSION` function returns the TiDB version with additional build information. |
| [`TIDB_DECODE_SQL_DIGESTS(digests, stmtTruncateLength)`](#tidb_decode_sql_digests) | The `TIDB_DECODE_SQL_DIGESTS()` function is used to query the normalized SQL statements (a form without formats and arguments) corresponding to the set of SQL digests in the cluster. |
| `VITESS_HASH(str)` | The `VITESS_HASH` function returns the hash of a string that is compatible with Vitess' `HASH` function. This is intended to help the data migration from Vitess. |
| `TIDB_SHARD()` | The `TIDB_SHARD` function can be used to create a shard index to scatter the index hotspot. A shard index is an expression index with a `TIDB_SHARD` function as the prefix.|

## Examples

Expand Down Expand Up @@ -230,3 +231,69 @@ See also:

- [`Statement Summary Tables`](/statement-summary-tables.md)
- [`INFORMATION_SCHEMA.TIDB_TRX`](/information-schema/information-schema-tidb-trx.md)

### TIDB_SHARD

The `TIDB_SHARD` function can be used to create a shard index to scatter the index hotspot. A shard index is an expression index prefixed with a `TIDB_SHARD` function.

#### Shard index

- Creation:

To create a shard index for the index field `a`, you can use `uk((tidb_shard(a)), a))`. When there is a hotspot caused by monotonically increasing or decreasing data on the index field `a` in the unique secondary index `uk((tidb_shard(a)), a))`, the index's prefix `tidb_shard(a)` can scatter the hotspot to improve the scalability of the cluster.

- Scenarios:

- There is a write hotspot caused by monotonically increasing or decreasing keys on the unique secondary index, and the index contains integer type fields.
- The SQL statement executes an equality query based on all fields of the secondary index, either as a separate `SELECT` or as an internal query generated by `UPDATE`, `DELETE` and so on. The equality query includes two ways: `a = 1` or `a IN (1, 2, ......)`.

- Limitations:

- Cannot be used in inequality queries.
- Cannot be used in queries that contain `OR` mixed with an outmost `AND` operator.
- Cannot be used in the `GROUP BY` clause.
- Cannot be used in the `ORDER BY` clause.
- Cannot be used in the `ON` clause.
- Cannot be used in the `WHERE` subquery.
- Can be used to scatter unique indexes of only the integer fields.
- Might not take effect in composite indexes.
- Cannot go through FastPlan process, which affects optimizer performance.
- Cannot be used to prepare the execution plan cache.

#### Synopsis

```ebnf+diagram
TIDBShardExpr ::=
"TIDB_SHARD" "(" expr ")"
```

#### Example

- Use the `TIDB_SHARD` function to calculate the SHARD value.

The following statement shows how to use the `TIDB_SHARD` function to calculate the SHARD value of `12373743746`:

{{< copyable "sql" >}}

```sql
SELECT TIDB_SHARD(12373743746);
```

- The SHARD value is:

```sql
+-------------------------+
| TIDB_SHARD(12373743746) |
+-------------------------+
| 184 |
+-------------------------+
1 row in set (0.00 sec)
```

- Create a shard index using the `TIDB_SHARD` function:

{{< copyable "sql" >}}

```sql
CREATE TABLE test(id INT PRIMARY KEY CLUSTERED, a INT, b INT, UNIQUE KEY uk((tidb_shard(a)), a));
```