From 2917e41cd8b672afd46c15138d45652688137b1e Mon Sep 17 00:00:00 2001 From: Jeffrey Smith II Date: Tue, 22 Oct 2024 11:23:17 -0400 Subject: [PATCH 1/2] feat: Update for latest SQL timezone behavior --- .../reference/sql/data-types.md | 8 +-- .../reference/sql/functions/time-and-date.md | 68 +++++++++++++++++++ .../reference/sql/operators/other.md | 4 +- .../reference/sql/data-types.md | 8 +-- .../reference/sql/functions/time-and-date.md | 68 +++++++++++++++++++ .../reference/sql/operators/other.md | 4 +- .../clustered/reference/sql/data-types.md | 8 +-- .../reference/sql/functions/time-and-date.md | 68 +++++++++++++++++++ .../reference/sql/operators/other.md | 2 +- 9 files changed, 221 insertions(+), 17 deletions(-) diff --git a/content/influxdb/cloud-dedicated/reference/sql/data-types.md b/content/influxdb/cloud-dedicated/reference/sql/data-types.md index df30af42e2..1bf904bce5 100644 --- a/content/influxdb/cloud-dedicated/reference/sql/data-types.md +++ b/content/influxdb/cloud-dedicated/reference/sql/data-types.md @@ -132,10 +132,10 @@ Floats can be a decimal point, decimal integer, or decimal fraction. InfluxDB SQL supports the following DATE/TIME data types: -| SQL data type | Arrow data type | Description | -| :------------ | :--------------------------------- | :------------------------------------------- | -| TIMESTAMP | Timestamp(Nanosecond, Some("UTC")) | Nanosecond timestamp with a time zone offset | -| INTERVAL | Interval(IntervalMonthDayNano) | Interval of time with a specified duration | +| SQL data type | Arrow data type | Description | +| :------------ | :--------------------------------- | :-------------------------------------------- | +| TIMESTAMP | Timestamp(Nanosecond, None) | Nanosecond timestamp with no time zone offset | +| INTERVAL | Interval(IntervalMonthDayNano) | Interval of time with a specified duration | ### Timestamp diff --git a/content/influxdb/cloud-dedicated/reference/sql/functions/time-and-date.md b/content/influxdb/cloud-dedicated/reference/sql/functions/time-and-date.md index b89a471025..a431d2679d 100644 --- a/content/influxdb/cloud-dedicated/reference/sql/functions/time-and-date.md +++ b/content/influxdb/cloud-dedicated/reference/sql/functions/time-and-date.md @@ -34,6 +34,7 @@ InfluxDB's SQL implementation supports time and date functions that are useful w - [to_timestamp_nanos](#to_timestamp_nanos) - [to_timestamp_seconds](#to_timestamp_seconds) - [to_unixtime](#to_unixtime) +- [tz](#tz) ## current_date @@ -1072,3 +1073,70 @@ SELECT {{% /expand %}} {{< /expand-wrapper >}} + + +## tz + +Converts a timestamp to a provided timezone. If the second argument is not provided, it defaults to UTC. + +```sql +tz(time[, timezone]) +``` + +##### Arguments + +- **expression**: time to operate on. + Can be a constant, column, or function, and any combination of arithmetic operators. +- **timezone**: Optional [timezone db string](https://en.wikipedia.org/wiki/List_of_tz_database_time_zones) into which the value should be cast. Defaults to "UTC" if not provided + The function returns the timestamp cast to the correct timezone. + If an incorrect timezone string is passed, or the wrong datatype is provided, the function returns an error. + +{{< expand-wrapper >}} +{{% expand "View `tz` query example" %}} + +```sql +SELECT tz('2024-01-01T01:00:00Z', 'America/New_York') AS time_tz +``` + +| time_tz | +| :----------------------- | +| 2024-10-01T02:00:00-04:00| + +{{% /expand %}} +{{% expand "View `tz` query example from Getting Started data" %}} + +```sql +SELECT tz(time, 'Australia/Sydney') AS time_tz, time FROM home ORDER BY time LIMIT 3; +``` + +| time_tz | time | +| :---------------------------------- | ------------------------------ | +| 1970-01-01T10:00:01.728979200+10:00 | 1970-01-01T00:00:01.728979200Z | +| 1970-01-01T10:00:01.728979200+10:00 | 1970-01-01T00:00:01.728979200Z | +| 1970-01-01T10:00:01.728982800+10:00 | 1970-01-01T00:00:01.728982800Z | + +{{% /expand %}} +{{< /expand-wrapper >}} + +##### What is the difference between tz and AT TIME ZONE? +`tz` and [AT TIME ZONE](../operators/other/#at-time-zone) have similar behavior that differs when the input timestamp **does not** have a timezone associated with it. + +When a timestamp does not have a timezone associated with it (the default behavior in InfluxDB 3.0), `AT TIME ZONE` will cast a timestamp to the "wall clock" time in a particular time zone. This is the moment in time something would be experienced in a given time zone. This is a good way to define bounds on a query when you want them relative to some known range in a timezone (for example your local time). +If a timezone is associated with the timestamp, then `AT TIME ZONE` will behave the same as `tz`. + +`tz` will **always** cast a timestamp to the "absolute" time in a particular time zone. This is a time relative to the unix epoch that has then be converted to that point in time in a given time zone. This is useful when you have data that was written as UTC or epoch timestamps, and you would like to view them in a specific timezone. + +{{< expand-wrapper >}} +{{% expand "View `tz` and `::timestamp` comparison" %}} +```sql +SELECT + '2024-04-01T00:00:20Z'::timestamp AT TIME ZONE 'Europe/Brussels' as time_timestamp, + tz('2024-04-01T00:00:20', 'Europe/Brussels') as time_tz; +``` + +| time_timestamp | time_tz | +| :--------------------------- | :------------------------- | +| 2024-04-01T00:00:20+02:00 | 2024-04-01T02:00:20+02:00 | + +{{% /expand %}} +{{< /expand-wrapper >}} diff --git a/content/influxdb/cloud-dedicated/reference/sql/operators/other.md b/content/influxdb/cloud-dedicated/reference/sql/operators/other.md index d3b8a10639..e5e99ba2c5 100644 --- a/content/influxdb/cloud-dedicated/reference/sql/operators/other.md +++ b/content/influxdb/cloud-dedicated/reference/sql/operators/other.md @@ -75,7 +75,7 @@ SELECT ```sql SELECT - '2024-01-01 00:00:00'::TIMESTAMP AT TIME ZONE 'America/Los_Angeles' AS 'Local time with TZ offset' + '2024-01-01 00:00:00' AT TIME ZONE 'America/Los_Angeles' AS 'Local time with TZ offset' ``` | Local time with TZ offset | @@ -83,4 +83,4 @@ SELECT | 2024-01-01T00:00:00-08:00 | {{% /expand %}} -{{< /expand-wrapper >}} \ No newline at end of file +{{< /expand-wrapper >}} diff --git a/content/influxdb/cloud-serverless/reference/sql/data-types.md b/content/influxdb/cloud-serverless/reference/sql/data-types.md index e922552a51..f2936ce620 100644 --- a/content/influxdb/cloud-serverless/reference/sql/data-types.md +++ b/content/influxdb/cloud-serverless/reference/sql/data-types.md @@ -132,10 +132,10 @@ Floats can be a decimal point, decimal integer, or decimal fraction. InfluxDB SQL supports the following DATE/TIME data types: -| SQL data type | Arrow data type | Description | -| :------------ | :--------------------------------- | :------------------------------------------- | -| TIMESTAMP | Timestamp(Nanosecond, Some("UTC")) | Nanosecond timestamp with a time zone offset | -| INTERVAL | Interval(IntervalMonthDayNano) | Interval of time with a specified duration | +| SQL data type | Arrow data type | Description | +| :------------ | :--------------------------------- | :-------------------------------------------- | +| TIMESTAMP | Timestamp(Nanosecond, None) | Nanosecond timestamp with no time zone offset | +| INTERVAL | Interval(IntervalMonthDayNano) | Interval of time with a specified duration | ### Timestamp diff --git a/content/influxdb/cloud-serverless/reference/sql/functions/time-and-date.md b/content/influxdb/cloud-serverless/reference/sql/functions/time-and-date.md index 4e4f7ab62b..b5be4cf878 100644 --- a/content/influxdb/cloud-serverless/reference/sql/functions/time-and-date.md +++ b/content/influxdb/cloud-serverless/reference/sql/functions/time-and-date.md @@ -34,6 +34,7 @@ InfluxDB's SQL implementation supports time and date functions that are useful w - [to_timestamp_nanos](#to_timestamp_nanos) - [to_timestamp_seconds](#to_timestamp_seconds) - [to_unixtime](#to_unixtime) +- [tz](#tz) ## current_date @@ -1072,3 +1073,70 @@ SELECT {{% /expand %}} {{< /expand-wrapper >}} + + +## tz + +Converts a timestamp to a provided timezone. If the second argument is not provided, it defaults to UTC. + +```sql +tz(time[, timezone]) +``` + +##### Arguments + +- **expression**: time to operate on. + Can be a constant, column, or function, and any combination of arithmetic operators. +- **timezone**: Optional [timezone db string](https://en.wikipedia.org/wiki/List_of_tz_database_time_zones) into which the value should be cast. Defaults to "UTC" if not provided + The function returns the timestamp cast to the correct timezone. + If an incorrect timezone string is passed, or the wrong datatype is provided, the function returns an error. + +{{< expand-wrapper >}} +{{% expand "View `tz` query example" %}} + +```sql +SELECT tz('2024-01-01T01:00:00Z', 'America/New_York') AS time_tz +``` + +| time_tz | +| :----------------------- | +| 2024-10-01T02:00:00-04:00| + +{{% /expand %}} +{{% expand "View `tz` query example from Getting Started data" %}} + +```sql +SELECT tz(time, 'Australia/Sydney') AS time_tz, time FROM home ORDER BY time LIMIT 3; +``` + +| time_tz | time | +| :---------------------------------- | ------------------------------ | +| 1970-01-01T10:00:01.728979200+10:00 | 1970-01-01T00:00:01.728979200Z | +| 1970-01-01T10:00:01.728979200+10:00 | 1970-01-01T00:00:01.728979200Z | +| 1970-01-01T10:00:01.728982800+10:00 | 1970-01-01T00:00:01.728982800Z | + +{{% /expand %}} +{{< /expand-wrapper >}} + +##### What is the difference between tz and AT TIME ZONE? +`tz` and [AT TIME ZONE](../operators/other/#at-time-zone) have similar behavior that differs when the input timestamp **does not** have a timezone associated with it. + +When a timestamp does not have a timezone associated with it (the default behavior in InfluxDB 3.0), `AT TIME ZONE` will cast a timestamp to the "wall clock" time in a particular time zone. This is the moment in time something would be experienced in a given time zone. This is a good way to define bounds on a query when you want them relative to some known range in a timezone (for example your local time). +If a timezone is associated with the timestamp, then `AT TIME ZONE` will behave the same as `tz`. + +`tz` will **always** cast a timestamp to the "absolute" time in a particular time zone. This is a time relative to the unix epoch that has then be converted to that point in time in a given time zone. This is useful when you have data that was written as UTC or epoch timestamps, and you would like to view them in a specific timezone. + +{{< expand-wrapper >}} +{{% expand "View `tz` and `::timestamp` comparison" %}} +```sql +SELECT + '2024-04-01T00:00:20Z'::timestamp AT TIME ZONE 'Europe/Brussels' as time_timestamp, + tz('2024-04-01T00:00:20', 'Europe/Brussels') as time_tz; +``` + +| time_timestamp | time_tz | +| :--------------------------- | :------------------------- | +| 2024-04-01T00:00:20+02:00 | 2024-04-01T02:00:20+02:00 | + +{{% /expand %}} +{{< /expand-wrapper >}} \ No newline at end of file diff --git a/content/influxdb/cloud-serverless/reference/sql/operators/other.md b/content/influxdb/cloud-serverless/reference/sql/operators/other.md index 1c9c7e6dd6..b0444f6e53 100644 --- a/content/influxdb/cloud-serverless/reference/sql/operators/other.md +++ b/content/influxdb/cloud-serverless/reference/sql/operators/other.md @@ -74,7 +74,7 @@ SELECT ```sql SELECT - '2024-01-01 00:00:00'::TIMESTAMP AT TIME ZONE 'America/Los_Angeles' AS 'Local time with TZ offset' + '2024-01-01 00:00:00' AT TIME ZONE 'America/Los_Angeles' AS 'Local time with TZ offset' ``` | Local time with TZ offset | @@ -82,4 +82,4 @@ SELECT | 2024-01-01T00:00:00-08:00 | {{% /expand %}} -{{< /expand-wrapper >}} \ No newline at end of file +{{< /expand-wrapper >}} diff --git a/content/influxdb/clustered/reference/sql/data-types.md b/content/influxdb/clustered/reference/sql/data-types.md index 368808c9dc..5b924313de 100644 --- a/content/influxdb/clustered/reference/sql/data-types.md +++ b/content/influxdb/clustered/reference/sql/data-types.md @@ -132,10 +132,10 @@ Floats can be a decimal point, decimal integer, or decimal fraction. InfluxDB SQL supports the following DATE/TIME data types: -| SQL data type | Arrow data type | Description | -| :------------ | :--------------------------------- | :------------------------------------------- | -| TIMESTAMP | Timestamp(Nanosecond, Some("UTC")) | Nanosecond timestamp with a time zone offset | -| INTERVAL | Interval(IntervalMonthDayNano) | Interval of time with a specified duration | +| SQL data type | Arrow data type | Description | +| :------------ | :--------------------------------- | :-------------------------------------------- | +| TIMESTAMP | Timestamp(Nanosecond, None) | Nanosecond timestamp with no time zone offset | +| INTERVAL | Interval(IntervalMonthDayNano) | Interval of time with a specified duration | ### Timestamp diff --git a/content/influxdb/clustered/reference/sql/functions/time-and-date.md b/content/influxdb/clustered/reference/sql/functions/time-and-date.md index e52c45a2bf..c34f8b904e 100644 --- a/content/influxdb/clustered/reference/sql/functions/time-and-date.md +++ b/content/influxdb/clustered/reference/sql/functions/time-and-date.md @@ -34,6 +34,7 @@ InfluxDB's SQL implementation supports time and date functions that are useful w - [to_timestamp_nanos](#to_timestamp_nanos) - [to_timestamp_seconds](#to_timestamp_seconds) - [to_unixtime](#to_unixtime) +- [tz](#tz) ## current_date @@ -1072,3 +1073,70 @@ SELECT {{% /expand %}} {{< /expand-wrapper >}} + + +## tz + +Converts a timestamp to a provided timezone. If the second argument is not provided, it defaults to UTC. + +```sql +tz(time[, timezone]) +``` + +##### Arguments + +- **expression**: time to operate on. + Can be a constant, column, or function, and any combination of arithmetic operators. +- **timezone**: Optional [timezone db string](https://en.wikipedia.org/wiki/List_of_tz_database_time_zones) into which the value should be cast. Defaults to "UTC" if not provided + The function returns the timestamp cast to the correct timezone. + If an incorrect timezone string is passed, or the wrong datatype is provided, the function returns an error. + +{{< expand-wrapper >}} +{{% expand "View `tz` query example" %}} + +```sql +SELECT tz('2024-01-01T01:00:00Z', 'America/New_York') AS time_tz +``` + +| time_tz | +| :----------------------- | +| 2024-10-01T02:00:00-04:00| + +{{% /expand %}} +{{% expand "View `tz` query example from Getting Started data" %}} + +```sql +SELECT tz(time, 'Australia/Sydney') AS time_tz, time FROM home ORDER BY time LIMIT 3; +``` + +| time_tz | time | +| :---------------------------------- | ------------------------------ | +| 1970-01-01T10:00:01.728979200+10:00 | 1970-01-01T00:00:01.728979200Z | +| 1970-01-01T10:00:01.728979200+10:00 | 1970-01-01T00:00:01.728979200Z | +| 1970-01-01T10:00:01.728982800+10:00 | 1970-01-01T00:00:01.728982800Z | + +{{% /expand %}} +{{< /expand-wrapper >}} + +##### What is the difference between tz and AT TIME ZONE? +`tz` and [AT TIME ZONE](../operators/other/#at-time-zone) have similar behavior that differs when the input timestamp **does not** have a timezone associated with it. + +When a timestamp does not have a timezone associated with it (the default behavior in InfluxDB 3.0), `AT TIME ZONE` will cast a timestamp to the "wall clock" time in a particular time zone. This is the moment in time something would be experienced in a given time zone. This is a good way to define bounds on a query when you want them relative to some known range in a timezone (for example your local time). +If a timezone is associated with the timestamp, then `AT TIME ZONE` will behave the same as `tz`. + +`tz` will **always** cast a timestamp to the "absolute" time in a particular time zone. This is a time relative to the unix epoch that has then be converted to that point in time in a given time zone. This is useful when you have data that was written as UTC or epoch timestamps, and you would like to view them in a specific timezone. + +{{< expand-wrapper >}} +{{% expand "View `tz` and `::timestamp` comparison" %}} +```sql +SELECT + '2024-04-01T00:00:20Z'::timestamp AT TIME ZONE 'Europe/Brussels' as time_timestamp, + tz('2024-04-01T00:00:20', 'Europe/Brussels') as time_tz; +``` + +| time_timestamp | time_tz | +| :--------------------------- | :------------------------- | +| 2024-04-01T00:00:20+02:00 | 2024-04-01T02:00:20+02:00 | + +{{% /expand %}} +{{< /expand-wrapper >}} diff --git a/content/influxdb/clustered/reference/sql/operators/other.md b/content/influxdb/clustered/reference/sql/operators/other.md index bd49e040e5..e7966a20e4 100644 --- a/content/influxdb/clustered/reference/sql/operators/other.md +++ b/content/influxdb/clustered/reference/sql/operators/other.md @@ -74,7 +74,7 @@ SELECT ```sql SELECT - '2024-01-01 00:00:00'::TIMESTAMP AT TIME ZONE 'America/Los_Angeles' AS 'Local time with TZ offset' + '2024-01-01 00:00:00' AT TIME ZONE 'America/Los_Angeles' AS 'Local time with TZ offset' ``` | Local time with TZ offset | From 7a84ef875494d37dfd98e84f0e6c430bd30dc46e Mon Sep 17 00:00:00 2001 From: Jeffrey Smith II Date: Wed, 23 Oct 2024 09:25:31 -0400 Subject: [PATCH 2/2] fix: cleanup and improve wording Co-authored-by: Scott Anderson --- .../reference/sql/functions/time-and-date.md | 56 +++++++++++++------ .../reference/sql/functions/time-and-date.md | 54 +++++++++++++----- .../reference/sql/functions/time-and-date.md | 56 +++++++++++++------ 3 files changed, 119 insertions(+), 47 deletions(-) diff --git a/content/influxdb/cloud-dedicated/reference/sql/functions/time-and-date.md b/content/influxdb/cloud-dedicated/reference/sql/functions/time-and-date.md index a431d2679d..0df3a88ebd 100644 --- a/content/influxdb/cloud-dedicated/reference/sql/functions/time-and-date.md +++ b/content/influxdb/cloud-dedicated/reference/sql/functions/time-and-date.md @@ -1080,16 +1080,17 @@ SELECT Converts a timestamp to a provided timezone. If the second argument is not provided, it defaults to UTC. ```sql -tz(time[, timezone]) +tz(time_expression[, timezone]) ``` ##### Arguments -- **expression**: time to operate on. +- **time_expression**: time to operate on. Can be a constant, column, or function, and any combination of arithmetic operators. -- **timezone**: Optional [timezone db string](https://en.wikipedia.org/wiki/List_of_tz_database_time_zones) into which the value should be cast. Defaults to "UTC" if not provided - The function returns the timestamp cast to the correct timezone. - If an incorrect timezone string is passed, or the wrong datatype is provided, the function returns an error. +- **timezone**: [Timezone string](https://en.wikipedia.org/wiki/List_of_tz_database_time_zones) + to cast the value into. Default is `'UTC'`. + The function returns the timestamp cast to the specified timezone. + If an incorrect timezone string is passed or the wrong datatype is provided, the function returns an error. {{< expand-wrapper >}} {{% expand "View `tz` query example" %}} @@ -1118,14 +1119,39 @@ SELECT tz(time, 'Australia/Sydney') AS time_tz, time FROM home ORDER BY time LIM {{% /expand %}} {{< /expand-wrapper >}} -##### What is the difference between tz and AT TIME ZONE? -`tz` and [AT TIME ZONE](../operators/other/#at-time-zone) have similar behavior that differs when the input timestamp **does not** have a timezone associated with it. - -When a timestamp does not have a timezone associated with it (the default behavior in InfluxDB 3.0), `AT TIME ZONE` will cast a timestamp to the "wall clock" time in a particular time zone. This is the moment in time something would be experienced in a given time zone. This is a good way to define bounds on a query when you want them relative to some known range in a timezone (for example your local time). -If a timezone is associated with the timestamp, then `AT TIME ZONE` will behave the same as `tz`. - -`tz` will **always** cast a timestamp to the "absolute" time in a particular time zone. This is a time relative to the unix epoch that has then be converted to that point in time in a given time zone. This is useful when you have data that was written as UTC or epoch timestamps, and you would like to view them in a specific timezone. - +##### Differences between tz and AT TIME ZONE +`tz` and [`AT TIME ZONE`](/influxdb/cloud-dedicated/reference/sql/operators/other/#at-time-zone) +differ when the input timestamp **does not** have a timezone. +- When using an input timestamp that does not have a timezone (the default behavior in InfluxDB) with the + `AT TIME ZONE` operator, the operator returns the the same timestamp, but with a timezone offset + (also known as the "wall clock" time)--for example: + ```sql + '2024-01-01 00:00:00'::TIMESTAMP AT TIME ZONE 'America/Los_Angeles' + + -- Returns + 2024-01-01T00:00:00-08:00 + ``` +- When using an input timestamp with a timezone, both the `tz()` function and the `AT TIME ZONE` + operator return the timestamp converted to the time in the specified timezone--for example: + ```sql + '2024-01-01T00:00:00-00:00' AT TIME ZONE 'America/Los_Angeles' + tz('2024-01-01T00:00:00-00:00', 'America/Los_Angeles') + + -- Both return + 2023-12-31T16:00:00-08:00 + ``` +- `tz()` always converts the input timestamp to the specified time zone. + If the input timestamp does not have a timezone, the function assumes it is a UTC timestamp--for example: + ```sql + tz('2024-01-01 00:00:00'::TIMESTAMP, 'America/Los_Angeles') + -- Returns + 2023-12-31T16:00:00-08:00 + ``` + ```sql + tz('2024-01-01T00:00:00+1:00', 'America/Los_Angeles') + -- Returns + 2023-12-31T15:00:00-08:00 + ``` {{< expand-wrapper >}} {{% expand "View `tz` and `::timestamp` comparison" %}} ```sql @@ -1133,10 +1159,8 @@ SELECT '2024-04-01T00:00:20Z'::timestamp AT TIME ZONE 'Europe/Brussels' as time_timestamp, tz('2024-04-01T00:00:20', 'Europe/Brussels') as time_tz; ``` - | time_timestamp | time_tz | | :--------------------------- | :------------------------- | | 2024-04-01T00:00:20+02:00 | 2024-04-01T02:00:20+02:00 | - {{% /expand %}} -{{< /expand-wrapper >}} +{{< /expand-wrapper >}} \ No newline at end of file diff --git a/content/influxdb/cloud-serverless/reference/sql/functions/time-and-date.md b/content/influxdb/cloud-serverless/reference/sql/functions/time-and-date.md index b5be4cf878..a61bc78ddd 100644 --- a/content/influxdb/cloud-serverless/reference/sql/functions/time-and-date.md +++ b/content/influxdb/cloud-serverless/reference/sql/functions/time-and-date.md @@ -1080,16 +1080,17 @@ SELECT Converts a timestamp to a provided timezone. If the second argument is not provided, it defaults to UTC. ```sql -tz(time[, timezone]) +tz(time_expression[, timezone]) ``` ##### Arguments -- **expression**: time to operate on. +- **time_expression**: time to operate on. Can be a constant, column, or function, and any combination of arithmetic operators. -- **timezone**: Optional [timezone db string](https://en.wikipedia.org/wiki/List_of_tz_database_time_zones) into which the value should be cast. Defaults to "UTC" if not provided - The function returns the timestamp cast to the correct timezone. - If an incorrect timezone string is passed, or the wrong datatype is provided, the function returns an error. +- **timezone**: [Timezone string](https://en.wikipedia.org/wiki/List_of_tz_database_time_zones) + to cast the value into. Default is `'UTC'`. + The function returns the timestamp cast to the specified timezone. + If an incorrect timezone string is passed or the wrong datatype is provided, the function returns an error. {{< expand-wrapper >}} {{% expand "View `tz` query example" %}} @@ -1118,14 +1119,39 @@ SELECT tz(time, 'Australia/Sydney') AS time_tz, time FROM home ORDER BY time LIM {{% /expand %}} {{< /expand-wrapper >}} -##### What is the difference between tz and AT TIME ZONE? -`tz` and [AT TIME ZONE](../operators/other/#at-time-zone) have similar behavior that differs when the input timestamp **does not** have a timezone associated with it. - -When a timestamp does not have a timezone associated with it (the default behavior in InfluxDB 3.0), `AT TIME ZONE` will cast a timestamp to the "wall clock" time in a particular time zone. This is the moment in time something would be experienced in a given time zone. This is a good way to define bounds on a query when you want them relative to some known range in a timezone (for example your local time). -If a timezone is associated with the timestamp, then `AT TIME ZONE` will behave the same as `tz`. - -`tz` will **always** cast a timestamp to the "absolute" time in a particular time zone. This is a time relative to the unix epoch that has then be converted to that point in time in a given time zone. This is useful when you have data that was written as UTC or epoch timestamps, and you would like to view them in a specific timezone. - +##### Differences between tz and AT TIME ZONE +`tz` and [`AT TIME ZONE`](/influxdb/cloud-serverless/reference/sql/operators/other/#at-time-zone) +differ when the input timestamp **does not** have a timezone. +- When using an input timestamp that does not have a timezone (the default behavior in InfluxDB) with the + `AT TIME ZONE` operator, the operator returns the the same timestamp, but with a timezone offset + (also known as the "wall clock" time)--for example: + ```sql + '2024-01-01 00:00:00'::TIMESTAMP AT TIME ZONE 'America/Los_Angeles' + + -- Returns + 2024-01-01T00:00:00-08:00 + ``` +- When using an input timestamp with a timezone, both the `tz()` function and the `AT TIME ZONE` + operator return the timestamp converted to the time in the specified timezone--for example: + ```sql + '2024-01-01T00:00:00-00:00' AT TIME ZONE 'America/Los_Angeles' + tz('2024-01-01T00:00:00-00:00', 'America/Los_Angeles') + + -- Both return + 2023-12-31T16:00:00-08:00 + ``` +- `tz()` always converts the input timestamp to the specified time zone. + If the input timestamp does not have a timezone, the function assumes it is a UTC timestamp--for example: + ```sql + tz('2024-01-01 00:00:00'::TIMESTAMP, 'America/Los_Angeles') + -- Returns + 2023-12-31T16:00:00-08:00 + ``` + ```sql + tz('2024-01-01T00:00:00+1:00', 'America/Los_Angeles') + -- Returns + 2023-12-31T15:00:00-08:00 + ``` {{< expand-wrapper >}} {{% expand "View `tz` and `::timestamp` comparison" %}} ```sql @@ -1133,10 +1159,8 @@ SELECT '2024-04-01T00:00:20Z'::timestamp AT TIME ZONE 'Europe/Brussels' as time_timestamp, tz('2024-04-01T00:00:20', 'Europe/Brussels') as time_tz; ``` - | time_timestamp | time_tz | | :--------------------------- | :------------------------- | | 2024-04-01T00:00:20+02:00 | 2024-04-01T02:00:20+02:00 | - {{% /expand %}} {{< /expand-wrapper >}} \ No newline at end of file diff --git a/content/influxdb/clustered/reference/sql/functions/time-and-date.md b/content/influxdb/clustered/reference/sql/functions/time-and-date.md index c34f8b904e..fdb363e812 100644 --- a/content/influxdb/clustered/reference/sql/functions/time-and-date.md +++ b/content/influxdb/clustered/reference/sql/functions/time-and-date.md @@ -1080,16 +1080,17 @@ SELECT Converts a timestamp to a provided timezone. If the second argument is not provided, it defaults to UTC. ```sql -tz(time[, timezone]) +tz(time_expression[, timezone]) ``` ##### Arguments -- **expression**: time to operate on. +- **time_expression**: time to operate on. Can be a constant, column, or function, and any combination of arithmetic operators. -- **timezone**: Optional [timezone db string](https://en.wikipedia.org/wiki/List_of_tz_database_time_zones) into which the value should be cast. Defaults to "UTC" if not provided - The function returns the timestamp cast to the correct timezone. - If an incorrect timezone string is passed, or the wrong datatype is provided, the function returns an error. +- **timezone**: [Timezone string](https://en.wikipedia.org/wiki/List_of_tz_database_time_zones) + to cast the value into. Default is `'UTC'`. + The function returns the timestamp cast to the specified timezone. + If an incorrect timezone string is passed or the wrong datatype is provided, the function returns an error. {{< expand-wrapper >}} {{% expand "View `tz` query example" %}} @@ -1118,14 +1119,39 @@ SELECT tz(time, 'Australia/Sydney') AS time_tz, time FROM home ORDER BY time LIM {{% /expand %}} {{< /expand-wrapper >}} -##### What is the difference between tz and AT TIME ZONE? -`tz` and [AT TIME ZONE](../operators/other/#at-time-zone) have similar behavior that differs when the input timestamp **does not** have a timezone associated with it. - -When a timestamp does not have a timezone associated with it (the default behavior in InfluxDB 3.0), `AT TIME ZONE` will cast a timestamp to the "wall clock" time in a particular time zone. This is the moment in time something would be experienced in a given time zone. This is a good way to define bounds on a query when you want them relative to some known range in a timezone (for example your local time). -If a timezone is associated with the timestamp, then `AT TIME ZONE` will behave the same as `tz`. - -`tz` will **always** cast a timestamp to the "absolute" time in a particular time zone. This is a time relative to the unix epoch that has then be converted to that point in time in a given time zone. This is useful when you have data that was written as UTC or epoch timestamps, and you would like to view them in a specific timezone. - +##### Differences between tz and AT TIME ZONE +`tz` and [`AT TIME ZONE`](/influxdb/cloud-serverless/reference/sql/operators/other/#at-time-zone) +differ when the input timestamp **does not** have a timezone. +- When using an input timestamp that does not have a timezone (the default behavior in InfluxDB) with the + `AT TIME ZONE` operator, the operator returns the the same timestamp, but with a timezone offset + (also known as the "wall clock" time)--for example: + ```sql + '2024-01-01 00:00:00'::TIMESTAMP AT TIME ZONE 'America/Los_Angeles' + + -- Returns + 2024-01-01T00:00:00-08:00 + ``` +- When using an input timestamp with a timezone, both the `tz()` function and the `AT TIME ZONE` + operator return the timestamp converted to the time in the specified timezone--for example: + ```sql + '2024-01-01T00:00:00-00:00' AT TIME ZONE 'America/Los_Angeles' + tz('2024-01-01T00:00:00-00:00', 'America/Los_Angeles') + + -- Both return + 2023-12-31T16:00:00-08:00 + ``` +- `tz()` always converts the input timestamp to the specified time zone. + If the input timestamp does not have a timezone, the function assumes it is a UTC timestamp--for example: + ```sql + tz('2024-01-01 00:00:00'::TIMESTAMP, 'America/Los_Angeles') + -- Returns + 2023-12-31T16:00:00-08:00 + ``` + ```sql + tz('2024-01-01T00:00:00+1:00', 'America/Los_Angeles') + -- Returns + 2023-12-31T15:00:00-08:00 + ``` {{< expand-wrapper >}} {{% expand "View `tz` and `::timestamp` comparison" %}} ```sql @@ -1133,10 +1159,8 @@ SELECT '2024-04-01T00:00:20Z'::timestamp AT TIME ZONE 'Europe/Brussels' as time_timestamp, tz('2024-04-01T00:00:20', 'Europe/Brussels') as time_tz; ``` - | time_timestamp | time_tz | | :--------------------------- | :------------------------- | | 2024-04-01T00:00:20+02:00 | 2024-04-01T02:00:20+02:00 | - {{% /expand %}} -{{< /expand-wrapper >}} +{{< /expand-wrapper >}} \ No newline at end of file