2020-04-03 13:23:32 +00:00
---
2022-08-28 14:53:34 +00:00
slug: /en/sql-reference/functions/uuid-functions
2023-04-19 17:05:55 +00:00
sidebar_position: 205
2023-04-19 18:36:10 +00:00
sidebar_label: UUIDs
2020-04-03 13:23:32 +00:00
---
2023-04-19 18:36:10 +00:00
# Functions for Working with UUIDs
2019-01-15 08:04:52 +00:00
2022-06-02 10:55:18 +00:00
## generateUUIDv4
2019-01-15 08:04:52 +00:00
2024-04-28 09:50:42 +00:00
Generates a [version 4 ](https://tools.ietf.org/html/rfc4122#section-4.4 ) [UUID ](../data-types/uuid.md ).
2019-01-15 08:04:52 +00:00
2022-05-22 23:17:45 +00:00
**Syntax**
2020-03-20 10:10:48 +00:00
``` sql
2024-04-28 09:50:42 +00:00
generateUUIDv4([expr])
2019-01-15 08:04:52 +00:00
```
2022-05-22 23:17:45 +00:00
**Arguments**
2024-05-24 03:54:16 +00:00
- `expr` — An arbitrary [expression ](../syntax.md#syntax-expressions ) used to bypass [common subexpression elimination ](../functions/index.md#common-subexpression-elimination ) if the function is called multiple times in a query. The value of the expression has no effect on the returned UUID. Optional.
2022-05-22 23:17:45 +00:00
2019-01-15 08:04:52 +00:00
**Returned value**
2024-04-26 10:04:29 +00:00
A value of type UUIDv4.
2019-01-15 08:04:52 +00:00
2024-04-26 10:04:29 +00:00
**Example**
2019-01-15 08:04:52 +00:00
2024-04-26 10:04:29 +00:00
First, create a table with a column of type UUID, then insert a generated UUIDv4 into the table.
2019-01-15 08:04:52 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2024-04-26 10:04:29 +00:00
CREATE TABLE tab (uuid UUID) ENGINE = Memory;
2019-01-15 08:04:52 +00:00
2024-04-26 10:04:29 +00:00
INSERT INTO tab SELECT generateUUIDv4();
2019-01-15 08:04:52 +00:00
2024-04-26 10:04:29 +00:00
SELECT * FROM tab;
2019-09-23 15:31:46 +00:00
```
2020-03-20 10:10:48 +00:00
2024-04-28 09:50:42 +00:00
Result:
2023-01-04 14:46:36 +00:00
```response
2024-04-26 10:04:29 +00:00
┌─────────────────────────────────uuid─┐
2019-01-15 08:04:52 +00:00
│ f4bf890f-f9dc-4332-ad5c-0c18e73f28e9 │
└──────────────────────────────────────┘
```
2024-04-28 09:50:42 +00:00
**Example with multiple UUIDs generated per row**
2022-05-22 23:17:45 +00:00
```sql
2024-04-26 10:04:29 +00:00
SELECT generateUUIDv4(1), generateUUIDv4(2);
2022-05-22 23:17:45 +00:00
┌─generateUUIDv4(1)────────────────────┬─generateUUIDv4(2)────────────────────┐
│ 2d49dc6e-ddce-4cd0-afb8-790956df54c1 │ 8abf8c13-7dea-4fdf-af3e-0e18767770e6 │
└──────────────────────────────────────┴──────────────────────────────────────┘
```
2024-04-28 09:50:42 +00:00
## generateUUIDv7 {#generateUUIDv7}
2024-04-22 16:30:25 +00:00
2024-04-28 09:50:42 +00:00
Generates a [version 7 ](https://datatracker.ietf.org/doc/html/draft-peabody-dispatch-new-uuid-format-04 ) [UUID ](../data-types/uuid.md ).
2024-04-26 10:04:29 +00:00
The generated UUID contains the current Unix timestamp in milliseconds (48 bits), followed by version "7" (4 bits), a counter (42 bit) to distinguish UUIDs within a millisecond (including a variant field "2", 2 bit), and a random field (32 bits).
2024-04-28 09:50:42 +00:00
For any given timestamp (unix_ts_ms), the counter starts at a random value and is incremented by 1 for each new UUID until the timestamp changes.
In case the counter overflows, the timestamp field is incremented by 1 and the counter is reset to a random new start value.
2024-04-27 14:30:27 +00:00
2024-04-28 09:50:42 +00:00
Function `generateUUIDv7` guarantees that the counter field within a timestamp increments monotonically across all function invocations in concurrently running threads and queries.
2024-04-26 10:04:29 +00:00
2024-04-22 16:30:25 +00:00
```
0 1 2 3
0 1 2 3 4 5 6 7 8 9 0 1 2 3 4 5 6 7 8 9 0 1 2 3 4 5 6 7 8 9 0 1
├─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┤
| unix_ts_ms |
├─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┤
2024-04-27 14:30:27 +00:00
| unix_ts_ms | ver | counter_high_bits |
2024-04-22 16:30:25 +00:00
├─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┤
2024-04-27 14:30:27 +00:00
|var| counter_low_bits |
2024-04-22 16:30:25 +00:00
├─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┤
| rand_b |
└─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┘
```
2024-04-28 09:50:42 +00:00
:::note
As of April 2024, version 7 UUIDs are in draft status and their layout may change in future.
:::
2024-04-22 16:30:25 +00:00
**Syntax**
``` sql
2024-04-28 09:50:42 +00:00
generateUUIDv7([expr])
2024-04-22 16:30:25 +00:00
```
**Arguments**
2024-05-24 03:54:16 +00:00
- `expr` — An arbitrary [expression ](../syntax.md#syntax-expressions ) used to bypass [common subexpression elimination ](../functions/index.md#common-subexpression-elimination ) if the function is called multiple times in a query. The value of the expression has no effect on the returned UUID. Optional.
2024-04-22 16:30:25 +00:00
**Returned value**
2024-04-26 10:04:29 +00:00
A value of type UUIDv7.
2024-04-22 16:30:25 +00:00
2024-04-26 10:04:29 +00:00
**Example**
2024-04-22 16:30:25 +00:00
2024-04-26 10:04:29 +00:00
First, create a table with a column of type UUID, then insert a generated UUIDv7 into the table.
2024-04-22 16:30:25 +00:00
``` sql
2024-04-26 10:04:29 +00:00
CREATE TABLE tab (uuid UUID) ENGINE = Memory;
2024-04-22 16:30:25 +00:00
2024-04-26 10:04:29 +00:00
INSERT INTO tab SELECT generateUUIDv7();
2024-04-22 16:30:25 +00:00
2024-04-26 10:04:29 +00:00
SELECT * FROM tab;
2024-04-22 16:30:25 +00:00
```
2024-04-28 09:50:42 +00:00
Result:
2024-04-22 16:30:25 +00:00
```response
2024-04-26 10:04:29 +00:00
┌─────────────────────────────────uuid─┐
2024-04-22 16:30:25 +00:00
│ 018f05af-f4a8-778f-beee-1bedbc95c93b │
└──────────────────────────────────────┘
```
2024-04-28 09:50:42 +00:00
**Example with multiple UUIDs generated per row**
2024-04-22 16:30:25 +00:00
```sql
2024-04-26 10:04:29 +00:00
SELECT generateUUIDv7(1), generateUUIDv7(2);
2024-04-22 16:30:25 +00:00
┌─generateUUIDv7(1)────────────────────┬─generateUUIDv7(2)────────────────────┐
2024-04-27 14:30:27 +00:00
│ 018f05c9-4ab8-7b86-b64e-c9f03fbd45d1 │ 018f05c9-4ab8-7b86-b64e-c9f12efb7e16 │
2024-04-22 16:30:25 +00:00
└──────────────────────────────────────┴──────────────────────────────────────┘
```
2022-06-02 10:55:18 +00:00
## empty
2021-08-10 10:53:35 +00:00
Checks whether the input UUID is empty.
**Syntax**
```sql
empty(UUID)
```
The UUID is considered empty if it contains all zeros (zero UUID).
2024-04-26 10:04:29 +00:00
The function also works for [Arrays ](array-functions.md#function-empty ) and [Strings ](string-functions.md#empty ).
2021-08-10 10:53:35 +00:00
**Arguments**
2024-04-26 10:04:29 +00:00
- `x` — A UUID. [UUID ](../data-types/uuid.md ).
2021-08-10 10:53:35 +00:00
**Returned value**
2024-05-23 13:48:20 +00:00
- Returns `1` for an empty UUID or `0` for a non-empty UUID. [UInt8 ](../data-types/int-uint.md ).
2021-08-10 10:53:35 +00:00
**Example**
2021-08-10 11:06:37 +00:00
To generate the UUID value, ClickHouse provides the [generateUUIDv4 ](#uuid-function-generate ) function.
2021-08-10 10:53:35 +00:00
Query:
```sql
SELECT empty(generateUUIDv4());
```
Result:
2023-01-04 14:46:36 +00:00
```response
2021-08-10 10:53:35 +00:00
┌─empty(generateUUIDv4())─┐
│ 0 │
└─────────────────────────┘
```
2022-06-02 10:55:18 +00:00
## notEmpty
2021-08-10 10:53:35 +00:00
Checks whether the input UUID is non-empty.
**Syntax**
```sql
notEmpty(UUID)
```
The UUID is considered empty if it contains all zeros (zero UUID).
2024-04-26 10:04:29 +00:00
The function also works for [Arrays ](array-functions.md#function-notempty ) or [Strings ](string-functions.md#notempty ).
2021-08-10 10:53:35 +00:00
**Arguments**
2024-04-26 10:04:29 +00:00
- `x` — A UUID. [UUID ](../data-types/uuid.md ).
2021-08-10 10:53:35 +00:00
**Returned value**
2024-05-23 13:48:20 +00:00
- Returns `1` for a non-empty UUID or `0` for an empty UUID. [UInt8 ](../data-types/int-uint.md ).
2021-08-10 10:53:35 +00:00
**Example**
2021-08-10 11:06:37 +00:00
To generate the UUID value, ClickHouse provides the [generateUUIDv4 ](#uuid-function-generate ) function.
2021-08-10 10:53:35 +00:00
Query:
```sql
SELECT notEmpty(generateUUIDv4());
```
Result:
2023-01-04 14:46:36 +00:00
```response
2021-08-10 10:53:35 +00:00
┌─notEmpty(generateUUIDv4())─┐
│ 1 │
└────────────────────────────┘
```
2024-04-26 10:04:29 +00:00
## toUUID
2019-01-15 08:04:52 +00:00
2024-04-26 10:04:29 +00:00
Converts a value of type String to a UUID.
2019-01-15 08:04:52 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2024-04-26 10:04:29 +00:00
toUUID(string)
2019-01-15 08:04:52 +00:00
```
**Returned value**
The UUID type value.
**Usage example**
2020-03-20 10:10:48 +00:00
``` sql
2019-09-23 15:31:46 +00:00
SELECT toUUID('61f0c404-5cb3-11e7-907b-a6006ad3dba0') AS uuid
```
2020-03-20 10:10:48 +00:00
2024-04-28 09:50:42 +00:00
Result:
2023-01-04 14:46:36 +00:00
```response
2019-01-15 08:04:52 +00:00
┌─────────────────────────────────uuid─┐
│ 61f0c404-5cb3-11e7-907b-a6006ad3dba0 │
└──────────────────────────────────────┘
```
2024-04-26 10:04:29 +00:00
## toUUIDOrDefault
2023-01-04 14:46:36 +00:00
**Arguments**
2024-05-24 03:54:16 +00:00
- `string` — String of 36 characters or FixedString(36). [String ](../syntax.md#string ).
- `default` — UUID to be used as the default if the first argument cannot be converted to a UUID type. [UUID ](../data-types/uuid.md ).
2023-01-04 14:46:36 +00:00
**Returned value**
UUID
``` sql
2024-04-26 10:04:29 +00:00
toUUIDOrDefault(string, default)
2023-01-04 14:46:36 +00:00
```
**Returned value**
The UUID type value.
**Usage examples**
This first example returns the first argument converted to a UUID type as it can be converted:
``` sql
SELECT toUUIDOrDefault('61f0c404-5cb3-11e7-907b-a6006ad3dba0', cast('59f0c404-5cb3-11e7-907b-a6006ad3dba0' as UUID));
```
2024-04-28 09:50:42 +00:00
Result:
2023-01-04 14:46:36 +00:00
```response
┌─toUUIDOrDefault('61f0c404-5cb3-11e7-907b-a6006ad3dba0', CAST('59f0c404-5cb3-11e7-907b-a6006ad3dba0', 'UUID'))─┐
│ 61f0c404-5cb3-11e7-907b-a6006ad3dba0 │
└───────────────────────────────────────────────────────────────────────────────────────────────────────────────┘
```
This second example returns the second argument (the provided default UUID) as the first argument cannot be converted to a UUID type:
```sql
SELECT toUUIDOrDefault('-----61f0c404-5cb3-11e7-907b-a6006ad3dba0', cast('59f0c404-5cb3-11e7-907b-a6006ad3dba0' as UUID));
```
2024-04-28 09:50:42 +00:00
Result:
2023-01-04 14:46:36 +00:00
```response
┌─toUUIDOrDefault('-----61f0c404-5cb3-11e7-907b-a6006ad3dba0', CAST('59f0c404-5cb3-11e7-907b-a6006ad3dba0', 'UUID'))─┐
│ 59f0c404-5cb3-11e7-907b-a6006ad3dba0 │
└────────────────────────────────────────────────────────────────────────────────────────────────────────────────────┘
```
2024-04-26 10:04:29 +00:00
## toUUIDOrNull
2020-10-25 08:45:29 +00:00
2024-04-26 10:04:29 +00:00
Takes an argument of type String and tries to parse it into UUID. If failed, returns NULL.
2020-10-25 08:45:29 +00:00
``` sql
2024-04-26 10:04:29 +00:00
toUUIDOrNull(string)
2020-10-25 08:45:29 +00:00
```
**Returned value**
2020-10-26 13:00:49 +00:00
The Nullable(UUID) type value.
2020-10-25 08:45:29 +00:00
**Usage example**
``` sql
SELECT toUUIDOrNull('61f0c404-5cb3-11e7-907b-a6006ad3dba0T') AS uuid
```
2024-04-28 09:50:42 +00:00
Result:
2023-01-04 14:46:36 +00:00
```response
2020-10-25 08:45:29 +00:00
┌─uuid─┐
│ ᴺᵁᴸᴸ │
└──────┘
```
2024-04-26 10:04:29 +00:00
## toUUIDOrZero
2020-10-25 08:45:29 +00:00
It takes an argument of type String and tries to parse it into UUID. If failed, returns zero UUID.
``` sql
2024-04-26 10:04:29 +00:00
toUUIDOrZero(string)
2020-10-25 08:45:29 +00:00
```
**Returned value**
The UUID type value.
**Usage example**
``` sql
SELECT toUUIDOrZero('61f0c404-5cb3-11e7-907b-a6006ad3dba0T') AS uuid
```
2024-04-28 09:50:42 +00:00
Result:
2023-01-04 14:46:36 +00:00
```response
2020-10-25 08:45:29 +00:00
┌─────────────────────────────────uuid─┐
│ 00000000-0000-0000-0000-000000000000 │
└──────────────────────────────────────┘
```
2022-06-02 10:55:18 +00:00
## UUIDStringToNum
2019-01-15 08:04:52 +00:00
2024-05-24 03:54:16 +00:00
Accepts `string` containing 36 characters in the format `xxxxxxxx-xxxx-xxxx-xxxx-xxxxxxxxxxxx` , and returns a [FixedString(16) ](../data-types/fixedstring.md ) as its binary representation, with its format optionally specified by `variant` (`Big-endian` by default).
2022-10-25 19:57:50 +00:00
**Syntax**
2019-01-15 08:04:52 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2022-10-25 19:57:50 +00:00
UUIDStringToNum(string[, variant = 1])
2019-01-15 08:04:52 +00:00
```
2022-10-25 19:57:50 +00:00
**Arguments**
2024-05-24 03:54:16 +00:00
- `string` — A [String ](../syntax.md#syntax-string-literal ) of 36 characters or [FixedString ](../syntax.md#syntax-string-literal )
2023-04-19 15:55:29 +00:00
- `variant` — Integer, representing a variant as specified by [RFC4122 ](https://datatracker.ietf.org/doc/html/rfc4122#section-4.1.1 ). 1 = `Big-endian` (default), 2 = `Microsoft` .
2022-10-25 19:57:50 +00:00
2019-01-15 08:04:52 +00:00
**Returned value**
FixedString(16)
**Usage examples**
2020-03-20 10:10:48 +00:00
``` sql
2019-09-23 15:31:46 +00:00
SELECT
2019-06-14 14:27:25 +00:00
'612f3c40-5d3b-217e-707b-6a546a3d7b29' AS uuid,
2019-01-15 08:04:52 +00:00
UUIDStringToNum(uuid) AS bytes
2019-09-23 15:31:46 +00:00
```
2020-03-20 10:10:48 +00:00
2024-04-28 09:50:42 +00:00
Result:
2023-01-04 14:46:36 +00:00
```response
2019-01-15 08:04:52 +00:00
┌─uuid─────────────────────────────────┬─bytes────────────┐
│ 612f3c40-5d3b-217e-707b-6a546a3d7b29 │ a/< @];!~p{jTj={) │
└──────────────────────────────────────┴──────────────────┘
```
2022-10-25 19:57:50 +00:00
``` sql
SELECT
'612f3c40-5d3b-217e-707b-6a546a3d7b29' AS uuid,
UUIDStringToNum(uuid, 2) AS bytes
```
2024-04-28 09:50:42 +00:00
Result:
2023-01-04 14:46:36 +00:00
```response
2022-10-25 19:57:50 +00:00
┌─uuid─────────────────────────────────┬─bytes────────────┐
│ 612f3c40-5d3b-217e-707b-6a546a3d7b29 │ @< /a;]~!p{jTj={) │
└──────────────────────────────────────┴──────────────────┘
```
2022-06-02 10:55:18 +00:00
## UUIDNumToString
2019-01-15 08:04:52 +00:00
2022-10-25 19:57:50 +00:00
Accepts `binary` containing a binary representation of a UUID, with its format optionally specified by `variant` (`Big-endian` by default), and returns a string containing 36 characters in text format.
**Syntax**
2019-01-15 08:04:52 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2022-10-25 19:57:50 +00:00
UUIDNumToString(binary[, variant = 1])
2019-01-15 08:04:52 +00:00
```
2022-10-25 19:57:50 +00:00
**Arguments**
2024-05-24 03:54:16 +00:00
- `binary` — [FixedString(16) ](../data-types/fixedstring.md ) as a binary representation of a UUID.
2023-04-19 15:55:29 +00:00
- `variant` — Integer, representing a variant as specified by [RFC4122 ](https://datatracker.ietf.org/doc/html/rfc4122#section-4.1.1 ). 1 = `Big-endian` (default), 2 = `Microsoft` .
2022-10-25 19:57:50 +00:00
2019-01-15 08:04:52 +00:00
**Returned value**
String.
**Usage example**
2020-03-20 10:10:48 +00:00
``` sql
2019-06-14 14:27:25 +00:00
SELECT
'a/< @];!~p{jTj={)' AS bytes,
2019-01-15 08:04:52 +00:00
UUIDNumToString(toFixedString(bytes, 16)) AS uuid
2019-09-23 15:31:46 +00:00
```
2020-03-20 10:10:48 +00:00
2024-04-28 09:50:42 +00:00
Result:
2023-01-04 14:46:36 +00:00
```response
2019-01-15 08:04:52 +00:00
┌─bytes────────────┬─uuid─────────────────────────────────┐
│ a/< @];!~p{jTj={) │ 612f3c40-5d3b-217e-707b-6a546a3d7b29 │
└──────────────────┴──────────────────────────────────────┘
```
2022-10-25 19:57:50 +00:00
``` sql
SELECT
'@< /a;]~!p{jTj={)' AS bytes,
UUIDNumToString(toFixedString(bytes, 16), 2) AS uuid
```
2024-04-28 09:50:42 +00:00
Result:
2023-01-04 14:46:36 +00:00
```response
2022-10-25 19:57:50 +00:00
┌─bytes────────────┬─uuid─────────────────────────────────┐
│ @< /a;]~!p{jTj={) │ 612f3c40-5d3b-217e-707b-6a546a3d7b29 │
└──────────────────┴──────────────────────────────────────┘
```
2024-04-22 16:30:25 +00:00
## UUIDToNum
2024-05-24 03:54:16 +00:00
Accepts a [UUID ](../data-types/uuid.md ) and returns its binary representation as a [FixedString(16) ](../data-types/fixedstring.md ), with its format optionally specified by `variant` (`Big-endian` by default). This function replaces calls to two separate functions `UUIDStringToNum(toString(uuid))` so no intermediate conversion from UUID to string is required to extract bytes from a UUID.
2024-04-22 16:30:25 +00:00
**Syntax**
``` sql
UUIDToNum(uuid[, variant = 1])
```
**Arguments**
- `uuid` — [UUID ](../data-types/uuid.md ).
- `variant` — Integer, representing a variant as specified by [RFC4122 ](https://datatracker.ietf.org/doc/html/rfc4122#section-4.1.1 ). 1 = `Big-endian` (default), 2 = `Microsoft` .
**Returned value**
2024-04-28 09:50:42 +00:00
The binary representation of the UUID.
2024-04-22 16:30:25 +00:00
**Usage examples**
``` sql
SELECT
toUUID('612f3c40-5d3b-217e-707b-6a546a3d7b29') AS uuid,
UUIDToNum(uuid) AS bytes
```
2024-04-28 09:50:42 +00:00
Result:
2024-04-22 16:30:25 +00:00
```response
┌─uuid─────────────────────────────────┬─bytes────────────┐
│ 612f3c40-5d3b-217e-707b-6a546a3d7b29 │ a/< @];!~p{jTj={) │
└──────────────────────────────────────┴──────────────────┘
```
``` sql
SELECT
toUUID('612f3c40-5d3b-217e-707b-6a546a3d7b29') AS uuid,
UUIDToNum(uuid, 2) AS bytes
```
2024-04-28 09:50:42 +00:00
Result:
2024-04-22 16:30:25 +00:00
```response
┌─uuid─────────────────────────────────┬─bytes────────────┐
│ 612f3c40-5d3b-217e-707b-6a546a3d7b29 │ @< /a;]~!p{jTj={) │
└──────────────────────────────────────┴──────────────────┘
```
2024-04-30 18:30:16 +00:00
## UUIDv7ToDateTime
Returns the timestamp component of a UUID version 7.
**Syntax**
``` sql
UUIDv7ToDateTime(uuid[, timezone])
```
**Arguments**
- `uuid` — [UUID ](../data-types/uuid.md ) of version 7.
2024-05-24 03:54:16 +00:00
- `timezone` — [Timezone name ](../../operations/server-configuration-parameters/settings.md#server_configuration_parameters-timezone ) for the returned value (optional). [String ](../data-types/string.md ).
2024-04-30 18:30:16 +00:00
**Returned value**
2024-05-24 03:54:16 +00:00
- Timestamp with milliseconds precision. If the UUID is not a valid version 7 UUID, it returns 1970-01-01 00:00:00.000. [DateTime64(3) ](../data-types/datetime64.md ).
2024-04-30 18:30:16 +00:00
**Usage examples**
``` sql
SELECT UUIDv7ToDateTime(toUUID('018f05c9-4ab8-7b86-b64e-c9f03fbd45d1'))
```
Result:
```response
┌─UUIDv7ToDateTime(toUUID('018f05c9-4ab8-7b86-b64e-c9f03fbd45d1'))─┐
│ 2024-04-22 15:30:29.048 │
└──────────────────────────────────────────────────────────────────┘
```
``` sql
SELECT UUIDv7ToDateTime(toUUID('018f05c9-4ab8-7b86-b64e-c9f03fbd45d1'), 'America/New_York')
```
Result:
```response
┌─UUIDv7ToDateTime(toUUID('018f05c9-4ab8-7b86-b64e-c9f03fbd45d1'), 'America/New_York')─┐
│ 2024-04-22 08:30:29.048 │
└──────────────────────────────────────────────────────────────────────────────────────┘
```
2024-05-23 17:14:06 +00:00
## serverUUID
2021-08-24 20:04:19 +00:00
2024-04-28 09:50:42 +00:00
Returns the random UUID generated during the first start of the ClickHouse server. The UUID is stored in file `uuid` in the ClickHouse server directory (e.g. `/var/lib/clickhouse/` ) and retained between server restarts.
2021-08-24 20:04:19 +00:00
**Syntax**
```sql
serverUUID()
```
**Returned value**
2024-05-23 14:39:53 +00:00
- The UUID of the server. [UUID ](../data-types/uuid.md ).
2021-08-24 20:04:19 +00:00
2024-05-22 16:26:48 +00:00
## generateSnowflakeID
2024-05-23 17:14:06 +00:00
Generates a [Snowflake ID ](https://en.wikipedia.org/wiki/Snowflake_ID ).
2024-05-22 16:26:48 +00:00
2024-05-23 17:14:06 +00:00
The generated Snowflake ID contains the current Unix timestamp in milliseconds 41 (+ 1 top zero bit) bits, followed by machine id (10 bits), a counter (12 bits) to distinguish IDs within a millisecond.
2024-05-22 16:26:48 +00:00
For any given timestamp (unix_ts_ms), the counter starts at 0 and is incremented by 1 for each new Snowflake ID until the timestamp changes.
In case the counter overflows, the timestamp field is incremented by 1 and the counter is reset to 0.
Function `generateSnowflakeID` guarantees that the counter field within a timestamp increments monotonically across all function invocations in concurrently running threads and queries.
```
0 1 2 3
0 1 2 3 4 5 6 7 8 9 0 1 2 3 4 5 6 7 8 9 0 1 2 3 4 5 6 7 8 9 0 1
├─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┤
|0| timestamp |
├─┼ ┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┤
| | machine_id | machine_seq_num |
└─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┘
```
**Syntax**
``` sql
generateSnowflakeID([expr])
```
**Arguments**
- `expr` — An arbitrary [expression ](../../sql-reference/syntax.md#syntax-expressions ) used to bypass [common subexpression elimination ](../../sql-reference/functions/index.md#common-subexpression-elimination ) if the function is called multiple times in a query. The value of the expression has no effect on the returned Snowflake ID. Optional.
**Returned value**
A value of type UInt64.
**Example**
First, create a table with a column of type UInt64, then insert a generated Snowflake ID into the table.
``` sql
CREATE TABLE tab (id UInt64) ENGINE = Memory;
INSERT INTO tab SELECT generateSnowflakeID();
SELECT * FROM tab;
```
Result:
```response
┌──────────────────id─┐
│ 7199081390080409600 │
└─────────────────────┘
```
**Example with multiple Snowflake IDs generated per row**
```sql
SELECT generateSnowflakeID(1), generateSnowflakeID(2);
┌─generateSnowflakeID(1)─┬─generateSnowflakeID(2)─┐
│ 7199081609652224000 │ 7199081609652224001 │
└────────────────────────┴────────────────────────┘
```
## generateSnowflakeIDThreadMonotonic
2024-05-23 17:14:06 +00:00
Generates a [Snowflake ID ](https://en.wikipedia.org/wiki/Snowflake_ID ).
2024-05-22 16:26:48 +00:00
2024-05-23 17:14:06 +00:00
The generated Snowflake ID contains the current Unix timestamp in milliseconds 41 (+ 1 top zero bit) bits, followed by machine id (10 bits), a counter (12 bits) to distinguish IDs within a millisecond.
For any given timestamp (unix_ts_ms), the counter starts at 0 and is incremented by 1 for each new Snowflake ID until the timestamp changes.
In case the counter overflows, the timestamp field is incremented by 1 and the counter is reset to 0.
2024-05-22 16:26:48 +00:00
2024-05-23 17:14:06 +00:00
This function behaves like `generateSnowflakeID` but gives no guarantee on counter monotony across different simultaneous requests.
Monotonicity within one timestamp is guaranteed only within the same thread calling this function to generate Snowflake IDs.
2024-05-22 16:26:48 +00:00
```
0 1 2 3
0 1 2 3 4 5 6 7 8 9 0 1 2 3 4 5 6 7 8 9 0 1 2 3 4 5 6 7 8 9 0 1
├─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┤
|0| timestamp |
├─┼ ┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┼─┤
| | machine_id | machine_seq_num |
└─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┴─┘
```
**Syntax**
``` sql
generateSnowflakeIDThreadMonotonic([expr])
```
**Arguments**
- `expr` — An arbitrary [expression ](../../sql-reference/syntax.md#syntax-expressions ) used to bypass [common subexpression elimination ](../../sql-reference/functions/index.md#common-subexpression-elimination ) if the function is called multiple times in a query. The value of the expression has no effect on the returned Snowflake ID. Optional.
**Returned value**
A value of type UInt64.
**Example**
First, create a table with a column of type UInt64, then insert a generated Snowflake ID into the table.
``` sql
CREATE TABLE tab (id UInt64) ENGINE = Memory;
INSERT INTO tab SELECT generateSnowflakeIDThreadMonotonic();
SELECT * FROM tab;
```
Result:
```response
┌──────────────────id─┐
│ 7199082832006627328 │
└─────────────────────┘
```
**Example with multiple Snowflake IDs generated per row**
```sql
SELECT generateSnowflakeIDThreadMonotonic(1), generateSnowflakeIDThreadMonotonic(2);
┌─generateSnowflakeIDThreadMonotonic(1)─┬─generateSnowflakeIDThreadMonotonic(2)─┐
│ 7199082940311945216 │ 7199082940316139520 │
└───────────────────────────────────────┴───────────────────────────────────────┘
```
2024-05-23 17:14:06 +00:00
## snowflakeToDateTime
2024-05-24 10:32:20 +00:00
Extracts the timestamp component of a [Snowflake ID ](https://en.wikipedia.org/wiki/Snowflake_ID ) in [DateTime ](../data-types/datetime.md ) format.
2024-05-23 17:14:06 +00:00
**Syntax**
``` sql
snowflakeToDateTime(value[, time_zone])
```
**Arguments**
2024-05-24 10:32:20 +00:00
- `value` — Snowflake ID. [Int64 ](../data-types/int-uint.md ).
- `time_zone` — [Timezone ](/docs/en/operations/server-configuration-parameters/settings.md/#server_configuration_parameters-timezone ). The function parses `time_string` according to the timezone. Optional. [String ](../data-types/string.md ).
2024-05-23 17:14:06 +00:00
**Returned value**
2024-05-24 10:32:20 +00:00
- The timestamp component of `value` as a [DateTime ](../data-types/datetime.md ) value.
2024-05-23 17:14:06 +00:00
**Example**
Query:
``` sql
SELECT snowflakeToDateTime(CAST('1426860702823350272', 'Int64'), 'UTC');
```
Result:
```response
┌─snowflakeToDateTime(CAST('1426860702823350272', 'Int64'), 'UTC')─┐
│ 2021-08-15 10:57:56 │
└──────────────────────────────────────────────────────────────────┘
```
## snowflakeToDateTime64
2024-05-24 10:32:20 +00:00
Extracts the timestamp component of a [Snowflake ID ](https://en.wikipedia.org/wiki/Snowflake_ID ) in [DateTime64 ](../data-types/datetime64.md ) format.
2024-05-23 17:14:06 +00:00
**Syntax**
``` sql
snowflakeToDateTime64(value[, time_zone])
```
**Arguments**
2024-05-24 10:32:20 +00:00
- `value` — Snowflake ID. [Int64 ](../data-types/int-uint.md ).
- `time_zone` — [Timezone ](/docs/en/operations/server-configuration-parameters/settings.md/#server_configuration_parameters-timezone ). The function parses `time_string` according to the timezone. Optional. [String ](../data-types/string.md ).
2024-05-23 17:14:06 +00:00
**Returned value**
2024-05-24 10:32:20 +00:00
- The timestamp component of `value` as a [DateTime64 ](../data-types/datetime64.md ) with scale = 3, i.e. millisecond precision.
2024-05-23 17:14:06 +00:00
**Example**
Query:
``` sql
SELECT snowflakeToDateTime64(CAST('1426860802823350272', 'Int64'), 'UTC');
```
Result:
```response
┌─snowflakeToDateTime64(CAST('1426860802823350272', 'Int64'), 'UTC')─┐
│ 2021-08-15 10:58:19.841 │
└────────────────────────────────────────────────────────────────────┘
```
## dateTimeToSnowflake
2024-05-24 10:32:20 +00:00
Converts a [DateTime ](../data-types/datetime.md ) value to the first [Snowflake ID ](https://en.wikipedia.org/wiki/Snowflake_ID ) at the giving time.
2024-05-23 17:14:06 +00:00
**Syntax**
``` sql
dateTimeToSnowflake(value)
```
**Arguments**
2024-05-24 10:32:20 +00:00
- `value` — Date with time. [DateTime ](../data-types/datetime.md ).
2024-05-23 17:14:06 +00:00
**Returned value**
2024-05-24 10:32:20 +00:00
- Input value converted to the [Int64 ](../data-types/int-uint.md ) data type as the first Snowflake ID at that time.
2024-05-23 17:14:06 +00:00
**Example**
Query:
``` sql
WITH toDateTime('2021-08-15 18:57:56', 'Asia/Shanghai') AS dt SELECT dateTimeToSnowflake(dt);
```
Result:
```response
┌─dateTimeToSnowflake(dt)─┐
│ 1426860702823350272 │
└─────────────────────────┘
```
## dateTime64ToSnowflake
2024-05-24 10:32:20 +00:00
Convert a [DateTime64 ](../data-types/datetime64.md ) to the first [Snowflake ID ](https://en.wikipedia.org/wiki/Snowflake_ID ) at the giving time.
2024-05-23 17:14:06 +00:00
**Syntax**
``` sql
dateTime64ToSnowflake(value)
```
**Arguments**
2024-05-24 10:32:20 +00:00
- `value` — Date with time. [DateTime64 ](../data-types/datetime64.md ).
2024-05-23 17:14:06 +00:00
**Returned value**
2024-05-24 10:32:20 +00:00
- Input value converted to the [Int64 ](../data-types/int-uint.md ) data type as the first Snowflake ID at that time.
2024-05-23 17:14:06 +00:00
**Example**
Query:
``` sql
WITH toDateTime64('2021-08-15 18:57:56.492', 3, 'Asia/Shanghai') AS dt64 SELECT dateTime64ToSnowflake(dt64);
```
Result:
```response
┌─dateTime64ToSnowflake(dt64)─┐
│ 1426860704886947840 │
└─────────────────────────────┘
```
2024-04-28 09:50:42 +00:00
## See also
2019-01-15 08:04:52 +00:00
2024-05-24 03:54:16 +00:00
- [dictGetUUID ](../functions/ext-dict-functions.md#ext_dict_functions-other )