Skip to content

Commit

Permalink
Update SQL timestamp functions and casting operations (influxdata#5332)
Browse files Browse the repository at this point in the history
* updated sql time and date functions

* update sql casting docs with new TIMESTAMP behavior, closes influxdata#5331

* Apply suggestions from code review

Co-authored-by: Jason Stirnaman <[email protected]>

* added format_n argument to to_timestamp* functions

---------

Co-authored-by: Jason Stirnaman <[email protected]>
  • Loading branch information
sanderson and jstirnaman authored Feb 26, 2024
1 parent 4ebfffa commit 3b9bf0d
Show file tree
Hide file tree
Showing 6 changed files with 501 additions and 121 deletions.
46 changes: 44 additions & 2 deletions content/influxdb/cloud-dedicated/query-data/sql/cast-types.md
Original file line number Diff line number Diff line change
Expand Up @@ -290,7 +290,7 @@ CAST(value AS TIMESTAMP)
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}

SQL supports casting the following to a boolean:
SQL supports casting the following to a timestamp:

- **Strings**: Returns the timestamp equivalent of the string value.
The following RFC3339 and RFC339-like string patterns are supported:
Expand All @@ -303,7 +303,49 @@ SQL supports casting the following to a boolean:
- `YYYY-MM-DD 00:00:00`
- `YYYY-MM-DD`

- **Integers**: Parses the integer as a Unix nanosecond timestamp and returns
- **Integers**: Parses the integer as a Unix _second_ timestamp and returns
the equivalent timestamp.
- **Unsigned integers**: Parses the unsigned integer as a Unix nanosecond timestamp
and returns the equivalent timestamp.

{{% note %}}
#### Cast Unix nanosecond timestamps to a timestamp type

To cast a Unix nanosecond timestamp to a timestamp type, first cast the numeric
value to an unsigned integer (`BIGINT UNSIGNED`) and then a timestamp.
You can also use the [`to_timestamp_nanos`](/influxdb/cloud-dedicated/reference/sql/functions/time-and-date/#to_timestamp_nanos)
function.

{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[:: shorthand](#)
[CAST()](#)
[to_timestamp_nanos](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
```sql
1704067200000000000::BIGINT UNSIGNED::TIMESTAMP
```
{{% /code-tab-content %}}
{{% code-tab-content %}}
```sql
CAST(CAST(1704067200000000000 AS BIGINT UNSIGNED) AS TIMESTAMP)
```
{{% /code-tab-content %}}
{{% code-tab-content %}}
```sql
to_timestamp_nanos(1704067200000000000)
```
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
{{% /note %}}

### Timestamp functions

You can also use the following SQL functions to cast a value to a timestamp type:

- [`to_timestamp`](/influxdb/cloud-dedicated/reference/sql/functions/time-and-date/#to_timestamp)
- [`to_timestamp_millis`](/influxdb/cloud-dedicated/reference/sql/functions/time-and-date/#to_timestamp_millis)
- [`to_timestamp_micros`](/influxdb/cloud-dedicated/reference/sql/functions/time-and-date/#to_timestamp_micros)
- [`to_timestamp_nanos`](/influxdb/cloud-dedicated/reference/sql/functions/time-and-date/#to_timestamp_nanos)
- [`to_timestamp_seconds`](/influxdb/cloud-dedicated/reference/sql/functions/time-and-date/#to_timestamp_seconds)
Original file line number Diff line number Diff line change
Expand Up @@ -26,6 +26,7 @@ InfluxDB's SQL implementation supports time and date functions that are useful w
- [to_timestamp](#to_timestamp)
- [to_timestamp_millis](#to_timestamp_millis)
- [to_timestamp_micros](#to_timestamp_micros)
- [to_timestamp_nanos](#to_timestamp_nanos)
- [to_timestamp_seconds](#to_timestamp_seconds)

## current_date
Expand Down Expand Up @@ -120,7 +121,8 @@ Calculates time intervals and returns the start of the interval nearest to the s
Use `date_bin` to downsample time series data by grouping rows into time-based "bins" or "windows"
and applying an aggregate or selector function to each window.

For example, if you "bin" or "window" data into 15 minute intervals, an input timestamp of `2023-01-01T18:18:18Z` will be updated to the start time of the 15 minute bin it is in: `2023-01-01T18:15:00Z`.
For example, given an input
timestamp of `2023-01-01T18:18:18Z`, if you bin data into 15-minute intervals, the output timestamp is `2023-01-01T18:15:00Z`--the start of the 15-minute bin that includes the input.

```sql
date_bin(interval, expression[, origin_timestamp])
Expand Down Expand Up @@ -608,10 +610,11 @@ WHERE

## to_timestamp

Converts a value to RFC3339 nanosecond timestamp format (`YYYY-MM-DDT00:00:00.000000000Z`).
Converts a value to RFC3339 timestamp format (`YYYY-MM-DDT00:00:00Z`).
Supports timestamp, integer, and unsigned integer types as input.
Integers and unsigned integers are parsed as [Unix nanosecond timestamps](/influxdb/cloud-dedicated/reference/glossary/#unix-timestamp)
and return the corresponding RFC3339 nanosecond timestamp.
Integers and unsigned integers are parsed as
[Unix nanosecond timestamps](/influxdb/cloud-dedicated/reference/glossary/#unix-timestamp)
and return the corresponding RFC3339 timestamp.

```sql
to_timestamp(expression)
Expand All @@ -626,14 +629,12 @@ to_timestamp(expression)
{{% expand "View `to_timestamp` query example" %}}

```sql
SELECT to_timestamp(time)
FROM h2o_feet
LIMIT 1
SELECT to_timestamp(1704067200000000000)
```

| totimestamp(cpu.time) |
| :----------------------- |
| 2019-08-27T00:00:00.000Z |
| to_timestamp(Int64(1704067200000000000)) |
| :--------------------------------------- |
| 2024-01-01T00:00:00Z |

{{% /expand %}}
{{< /expand-wrapper >}}
Expand All @@ -642,33 +643,46 @@ LIMIT 1

Converts a value to RFC3339 millisecond timestamp format (`YYYY-MM-DDT00:00:00.000Z`).
Supports timestamp, integer, and unsigned integer types as input.
Integers and unsigned integers are parsed as [Unix nanosecond timestamps](/influxdb/cloud-dedicated/reference/glossary/#unix-timestamp)
Integers and unsigned integers are parsed as
[Unix millisecond timestamps](/influxdb/cloud-dedicated/reference/glossary/#unix-timestamp)
and return the corresponding RFC3339 timestamp.

```sql
to_timestamp_millis(expression)
to_timestamp_millis(expression[, ..., format_n])
```

##### Arguments:

- **expression**: Expression to operate on.
Can be a constant, column, or function, and any combination of arithmetic operators.
- **format_n**: [Rust strftime](https://docs.rs/chrono/latest/chrono/format/strftime/index.html)
pattern to use to parse the _string_ expression.
Formats are attempted in the order that they appear.
The function returns the timestamp from the first format to parse successfully.
If no formats parse successfully, the function returns an error.

{{< expand-wrapper >}}
{{% expand "View `to_timestamp_millis` query example" %}}

```sql
SELECT
to_timestamp_millis(time)
FROM
h2o_temperature
LIMIT 1
SELECT to_timestamp_millis(1704067200001) AS time
```

Results
| totimestampmillis(cpu.time) |
| :-------------------------- |
| 2023-02-08T17:25:18.864Z |
| to_timestamp_millis(Int64(1704067200001)) |
| :---------------------------------------- |
| 2024-01-01T00:00:00.001Z |

{{% /expand %}}
{{% expand "View `to_timestamp_millis` example with string format parsing" %}}

```sql
SELECT to_timestamp_millis('01:01:59.123456789 01-01-2024', '%c', '%+', '%H:%M:%S%.f %m-%d-%Y') AS millisecond
```

| millisecond |
| :----------------------- |
| 2024-01-01T01:01:59.123Z |

{{% /expand %}}
{{< /expand-wrapper >}}
Expand All @@ -677,65 +691,137 @@ Results

Converts a value to RFC3339 microsecond timestamp format (`YYYY-MM-DDT00:00:00.000000Z`).
Supports timestamp, integer, and unsigned integer types as input.
Integers and unsigned integers are parsed as [Unix nanosecond timestamps](/influxdb/cloud-dedicated/reference/glossary/#unix-timestamp)
Integers and unsigned integers are parsed as
[Unix microsecond timestamps](/influxdb/cloud-dedicated/reference/glossary/#unix-timestamp)
and return the corresponding RFC3339 timestamp.

```sql
to_timestamp_micros(expression)
to_timestamp_micros(expression[, ..., format_n])
```

##### Arguments:

- **expression**: Expression to operate on.
Can be a constant, column, or function, and any combination of arithmetic operators.
- **format_n**: [Rust strftime](https://docs.rs/chrono/latest/chrono/format/strftime/index.html)
pattern to use to parse the _string_ expression.
Formats are attempted in the order that they appear.
The function returns the timestamp from the first format to parse successfully.
If no formats parse successfully, the function returns an error.

{{< expand-wrapper >}}
{{% expand "View `to_timestamp_micros` query example" %}}

```sql
SELECT
to_timestamp_micros(time)
FROM
cpu
LIMIT 1
SELECT to_timestamp_micros(1704067200000001)
```

| to_timestamp_micros(Int64(1704067200000001)) |
| :------------------------------------------- |
| 2024-01-01T00:00:00.000001Z |
{{% /expand %}}
{{% expand "View `to_timestamp_micros` example with string format parsing" %}}

```sql
SELECT to_timestamp_micros('01:01:59.123456789 01-01-2024', '%c', '%+', '%H:%M:%S%.f %m-%d-%Y') AS microsecond
```

| totimestampmicros(cpu.time) |
| microsecond |
| :-------------------------- |
| 2023-02-08T19:21:10.000Z |
| 2024-01-01T01:01:59.123456Z |

{{% /expand %}}
{{< /expand-wrapper >}}

## to_timestamp_nanos

Converts a value to RFC3339 nanosecond timestamp format (`YYYY-MM-DDT00:00:00.000000000Z`).
Supports timestamp, integer, and unsigned integer types as input.
Integers and unsigned integers are parsed as
[Unix nanosecond timestamps](/influxdb/cloud-dedicated/reference/glossary/#unix-timestamp)
and return the corresponding RFC3339 timestamp.

```sql
to_timestamp_nanos(expression[, ..., format_n])
```

##### Arguments:

- **expression**: Expression to operate on.
Can be a constant, column, or function, and any combination of arithmetic operators.
- **format_n**: [Rust strftime](https://docs.rs/chrono/latest/chrono/format/strftime/index.html)
pattern to use to parse the _string_ expression.
Formats are attempted in the order that they appear.
The function returns the timestamp from the first format to parse successfully.
If no formats parse successfully, the function returns an error.

{{< expand-wrapper >}}
{{% expand "View `to_timestamp_nanos` query example" %}}

```sql
SELECT to_timestamp_nanos(1704067200000000001)
```

| to_timestamp_nanos(Int64(1704067200000000001)) |
| :--------------------------------------------- |
| 2024-01-01T00:00:00.000000001Z |
{{% /expand %}}
{{% expand "View `to_timestamp_nanos` example with string format parsing" %}}

```sql
SELECT to_timestamp_nanos('01:01:59.123456789 01-01-2024', '%c', '%+', '%H:%M:%S%.f %m-%d-%Y') AS nanosecond
```

| nanosecond |
| :----------------------------- |
| 2024-01-01T01:01:59.123456789Z |

{{% /expand %}}
{{< /expand-wrapper >}}

## to_timestamp_seconds

Converts a value to RFC3339 second timestamp format (`YYYY-MM-DDT00:00:00Z`).
Supports timestamp, integer, and unsigned integer types as input.
Integers and unsigned integers are parsed as [Unix nanosecond timestamps](/influxdb/cloud-dedicated/reference/glossary/#unix-timestamp)
Integers and unsigned integers are parsed as
[Unix second timestamps](/influxdb/cloud-dedicated/reference/glossary/#unix-timestamp)
and return the corresponding RFC3339 timestamp.

```sql
to_timestamp_seconds(expression)
to_timestamp_seconds(expression[, ..., format_n])
```

##### Arguments:

- **expression**: Expression to operate on.
Can be a constant, column, or function, and any combination of arithmetic operators.
- **format_n**: [Rust strftime](https://docs.rs/chrono/latest/chrono/format/strftime/index.html)
pattern to use to parse the _string_ expression.
Formats are attempted in the order that they appear.
The function returns the timestamp from the first format to parse successfully.
If no formats parse successfully, the function returns an error.

{{< expand-wrapper >}}
{{% expand "View `to_timestamp_seconds` query example" %}}

```sql
SELECT
to_timestamp_seconds(time)
FROM
cpu
LIMIT 1;
SELECT to_timestamp_seconds(1704067201)
```

| totimestampseconds(cpu.time) |
| :--------------------------- |
| 2023-02-08T17:21:10 |
| to_timestamp_seconds(Int64(1704067201)) |
| :-------------------------------------- |
| 2024-01-01T00:00:01Z |

{{% /expand %}}
{{% expand "View `to_timestamp_seconds` example with string format parsing" %}}

```sql
SELECT to_timestamp_seconds('01:01:59.123456789 01-01-2024', '%c', '%+', '%H:%M:%S%.f %m-%d-%Y') AS second
```

| second |
| :------------------- |
| 2024-01-01T01:01:59Z |

{{% /expand %}}
{{< /expand-wrapper >}}
46 changes: 44 additions & 2 deletions content/influxdb/cloud-serverless/query-data/sql/cast-types.md
Original file line number Diff line number Diff line change
Expand Up @@ -290,7 +290,7 @@ CAST(value AS TIMESTAMP)
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}

SQL supports casting the following to a boolean:
SQL supports casting the following to a timestamp:

- **Strings**: Returns the timestamp equivalent of the string value.
The following RFC3339 and RFC339-like string patterns are supported:
Expand All @@ -303,7 +303,49 @@ SQL supports casting the following to a boolean:
- `YYYY-MM-DD 00:00:00`
- `YYYY-MM-DD`

- **Integers**: Parses the integer as a Unix nanosecond timestamp and returns
- **Integers**: Parses the integer as a Unix _second_ timestamp and returns
the equivalent timestamp.
- **Unsigned integers**: Parses the unsigned integer as a Unix nanosecond timestamp
and returns the equivalent timestamp.

{{% note %}}
#### Cast Unix nanosecond timestamps to a timestamp type

To cast a Unixnanosecond timestamp to a timestamp type, first cast the numeric
value to an unsigned integer (`BIGINT UNSIGNED`) and then a timestamp.
You can also use the [`to_timestamp_nanos`](/influxdb/cloud-serverless/reference/sql/functions/time-and-date/#to_timestamp_nanos)
function.

{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[:: shorthand](#)
[CAST()](#)
[to_timestamp_nanos](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
```sql
1704067200000000000::BIGINT UNSIGNED::TIMESTAMP
```
{{% /code-tab-content %}}
{{% code-tab-content %}}
```sql
CAST(CAST(1704067200000000000 AS BIGINT UNSIGNED) AS TIMESTAMP)
```
{{% /code-tab-content %}}
{{% code-tab-content %}}
```sql
to_timestamp_nanos(1704067200000000000)
```
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
{{% /note %}}

### Timestamp functions

You can also use the following SQL functions to cast a value to a timestamp type:

- [`to_timestamp`](/influxdb/cloud-serverless/reference/sql/functions/time-and-date/#to_timestamp)
- [`to_timestamp_millis`](/influxdb/cloud-serverless/reference/sql/functions/time-and-date/#to_timestamp_millis)
- [`to_timestamp_micros`](/influxdb/cloud-serverless/reference/sql/functions/time-and-date/#to_timestamp_micros)
- [`to_timestamp_nanos`](/influxdb/cloud-serverless/reference/sql/functions/time-and-date/#to_timestamp_nanos)
- [`to_timestamp_seconds`](/influxdb/cloud-serverless/reference/sql/functions/time-and-date/#to_timestamp_seconds)
Loading

0 comments on commit 3b9bf0d

Please sign in to comment.