Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
42 changes: 42 additions & 0 deletions best-practices/uuid.md
Original file line number Diff line number Diff line change
Expand Up @@ -19,6 +19,26 @@ When used as a primary key, a UUID offers the following advantages compared with

This section describes best practices for storing and indexing UUIDs in TiDB.

### UUID versions

[RFC 9562](https://datatracker.ietf.org/doc/html/rfc9562) defines 8 different versions of UUIDs. TiDB can store any version of UUID and can create v1, v4 and v7 UUIDs.

UUIDv1 is created with the [`UUID()`](/functions-and-operators/miscellaneous-functions.md#uuid) function.

UUIDv2 is not commonly used.

UUIDv3 uses a namespace with a MD5 hash.

UUIDv4 is created with the [`UUID_V4()`](/functions-and-operators/miscellaneous-functions.md#uuid_v4) function. This function does not store a timestamp and is fully random except for the bits that store the version and variant.

UUIDv5 uses a namespace with a SHA1 hash.

UUIDv6 is a modern alternative to UUIDv1 that is field compatible with UUIDv1.

UUIDv7 is created with the [`UUID_V7()`](/functions-and-operators/miscellaneous-functions.md#uuid_v7) function. This function is meant as a modern alternative to UUIDv1 for applications that don't require a UUID that is field compatible with UUIDv1.

UUIDv8 is a custom format UUID that only requires the version bits to be set to 0b1000 (binary representation of 8).

### Store as binary

The textual UUID format looks like this: `ab06f63e-8fe7-11ec-a514-5405db7aad56`, which is a string of 36 characters. By using [`UUID_TO_BIN()`](/functions-and-operators/miscellaneous-functions.md#uuid_to_bin), the textual format can be converted into a binary format of 16 bytes. This allows you to store the text in a [`BINARY(16)`](/data-type-string.md#binary-type) column. When retrieving the UUID, you can use the [`BIN_TO_UUID()`](/functions-and-operators/miscellaneous-functions.md#bin_to_uuid) function to get back to the textual format.
Expand Down Expand Up @@ -73,6 +93,28 @@ CREATE TABLE `uuid_demo_2` (
)
```

### Generated UUID as default

An expression default can be used to generate a UUID for a primary key. Replace `UUID()` with `UUID_V4()` or `UUID_V7()` to use a UUIDv4 or UUIDv7 instead of a UUIDv1 if needed.

```sql
CREATE TABLE `uuid_demo_3` (
`uuid` BINARY(16) DEFAULT (UUID_TO_BIN(UUID())),
PRIMARY KEY (`uuid`)
)
```

### Converting from binary to text using a generated column

```sql
CREATE TABLE `uuid_demo_4` (
`uuid` BINARY(16) PRIMARY KEY,
`uuid_text` CHAR(36) AS (BIN_TO_UUID(uuid))
);
```

## MySQL compatibility

UUIDs can be used in MySQL as well. The `BIN_TO_UUID()` and `UUID_TO_BIN()` functions were introduced in MySQL 8.0. The `UUID()` function is available in earlier MySQL versions as well.

The `UUID_V4()`, `UUID_V7()`, `UUID_VERSION()` and `UUID_TIMESTAMP()` functions are TiDB specific extensions.
122 changes: 119 additions & 3 deletions functions-and-operators/miscellaneous-functions.md
Original file line number Diff line number Diff line change
Expand Up @@ -27,8 +27,12 @@ TiDB supports most of the [miscellaneous functions](https://dev.mysql.com/doc/re
| [`IS_UUID()`](#is_uuid) | Whether argument is an UUID |
| [`NAME_CONST()`](#name_const) | Can be used to rename a column name |
| [`SLEEP()`](#sleep) | Sleep for a number of seconds. Note that for [{{{ .starter }}}](https://docs.pingcap.com/tidbcloud/select-cluster-tier#starter) and [{{{ .essential }}}](https://docs.pingcap.com/tidbcloud/select-cluster-tier#essential) clusters, the `SLEEP()` function has a limitation wherein it can only support a maximum sleep time of 300 seconds. |
| [`UUID()`](#uuid) | Return a Universal Unique Identifier (UUID) |
| [`UUID()`](#uuid) | Return a v1 Universal Unique Identifier (UUID) |
| [`UUID_TIMESTAMP()`](#uuid_timestamp) | Return the timestamp of a UUID |
| [`UUID_TO_BIN()`](#uuid_to_bin) | Convert UUID from text format to binary format |
| [`UUID_V4()`](#uuid_v4) | Return a v4 Universal Unique Identifier (UUID) |
| [`UUID_V7()`](#uuid_v7) | Return a v7 Universal Unique Identifier (UUID) |
| [`UUID_VERSION()`](#uuid_version) | Return the UUID version of a UUID |
| [`VALUES()`](#values) | Defines the values to be used during an INSERT |

### ANY_VALUE()
Expand Down Expand Up @@ -361,9 +365,117 @@ SELECT SLEEP(1.5);
1 row in set (1.50 sec)
```

### UUID_VERSION()

The `UUID_VERSION()` function returns the version of a UUID argument as an integer, as defined in [RFC 9562](https://datatracker.ietf.org/doc/html/rfc9562).

The following example gets the version number from a version 1 UUID.

```sql
SELECT UUID_VERSION('7d31138f-e0ee-11f0-a2db-86f42566cd2c');
```

```
+------------------------------------------------------+
| UUID_VERSION('7d31138f-e0ee-11f0-a2db-86f42566cd2c') |
+------------------------------------------------------+
| 1 |
+------------------------------------------------------+
1 row in set (0.001 sec)
```

The following example gets the version number from a version 7 UUID.

```sql
SELECT UUID_VERSION('019b516b-8ef7-7d74-81e6-9b860112409a');
```

```
+------------------------------------------------------+
| UUID_VERSION('019b516b-8ef7-7d74-81e6-9b860112409a') |
+------------------------------------------------------+
| 7 |
+------------------------------------------------------+
1 row in set (0.001 sec)
```

### UUID_V4()

The `UUID_V4()` function returns a universally unique identifier (UUID) version 4 as defined in [RFC 9562](https://datatracker.ietf.org/doc/html/rfc9562). A UUIDv4 is based on random values and does not store a timestamp.

```sql
SELECT UUID_V4();
```

```
+--------------------------------------+
| UUID_V4() |
+--------------------------------------+
| e76d4b18-7f8d-418d-8f9b-f42b4f1d803b |
+--------------------------------------+
1 row in set (0.001 sec)
```

See also [Best practices for UUID](/best-practices/uuid.md).

### UUID_V7()

The `UUID_V7()` function returns a universally unique identifier (UUID) version 7 as defined in [RFC 9562](https://datatracker.ietf.org/doc/html/rfc9562).

```sql
SELECT UUID_V7();
```

```
+--------------------------------------+
| UUID_V7() |
+--------------------------------------+
| 019b5171-c5e4-743a-b192-96fbb28d1d7e |
+--------------------------------------+
1 row in set (0.001 sec)
```

See also [Best practices for UUID](/best-practices/uuid.md).

### UUID_TIMESTAMP()

The `UUID_TIMESTAMP()` function extracts the timestamp from a time-based UUID and returns it as a UNIX timestamp.

UUIDv1, UUIDv6, and UUIDv7 store a timestamp. For other UUID versions, this function returns `NULL`.

The example below extracts the timestamp from a UUID.

```sql
SELECT UUID_TIMESTAMP('019b5171-c5e4-743a-b192-96fbb28d1d7e');
```

```
+--------------------------------------------------------+
| UUID_TIMESTAMP('019b5171-c5e4-743a-b192-96fbb28d1d7e') |
+--------------------------------------------------------+
| 1766597969.380000 |
+--------------------------------------------------------+
1 row in set (0.001 sec)
```

The resulting UNIX timestamp can be used directly with [`FROM_UNIXTIME()`](/functions-and-operators/date-and-time-functions.md) to get a timestamp.

```sql
SELECT FROM_UNIXTIME(1766597969.380000);
```

```
+----------------------------------+
| FROM_UNIXTIME(1766597969.380000) |
+----------------------------------+
| 2025-12-24 18:39:29.380000 |
+----------------------------------+
1 row in set (0.001 sec)
```

### UUID()

The `UUID()` function returns a universally unique identifier (UUID) version 1 as defined in [RFC 4122](https://datatracker.ietf.org/doc/html/rfc4122).
The `UUID()` function returns a universally unique identifier (UUID) version 1 as defined in [RFC 9562](https://datatracker.ietf.org/doc/html/rfc9562).

```sql
SELECT UUID();
Expand Down Expand Up @@ -417,4 +529,8 @@ TABLE t1;

| Name | Description |
|:------------|:-----------------------------------------------------------------------------------------------|
| [`UUID_SHORT()`](https://dev.mysql.com/doc/refman/8.0/en/miscellaneous-functions.html#function_uuid-short) | Provides a UUID that is unique given certain assumptions not present in TiDB [TiDB #4620](https://github.com/pingcap/tidb/issues/4620) |
| [`UUID_SHORT()`](https://dev.mysql.com/doc/refman/8.0/en/miscellaneous-functions.html#function_uuid-short) | Provides a UUID that is unique given certain assumptions not present in TiDB [TiDB #4620](https://github.com/pingcap/tidb/issues/4620) |

## MySQL compatibility

The `UUID_V4()`, `UUID_V7()`, `UUID_VERSION()` and `UUID_TIMESTAMP()` functions are TiDB specific extensions.