Add new date_bin_wallclock SQL functions (#5691)
* add new date_bin_wallclock sql fns * Apply suggestions from code review Co-authored-by: Jason Stirnaman <jstirnaman@influxdata.com> * updates to address PR feedback * Apply suggestions from code review Co-authored-by: Chunchun Ye <14298407+appletreeisyellow@users.noreply.github.com> * updates to address PR feedback * fixed typos --------- Co-authored-by: Jason Stirnaman <jstirnaman@influxdata.com> Co-authored-by: Chunchun Ye <14298407+appletreeisyellow@users.noreply.github.com>pull/5704/head^2
parent
096b3e387e
commit
e924c0a82d
|
@ -31,6 +31,7 @@ blockquote,
|
|||
position: absolute;
|
||||
font-family: "alert-icons";
|
||||
font-size: 1em;
|
||||
line-height: 1em;
|
||||
padding: .3rem;
|
||||
text-align: center;
|
||||
top: -.5rem;
|
||||
|
|
|
@ -56,7 +56,7 @@
|
|||
background: $article-caution-code-bg};
|
||||
}
|
||||
hr, .expand {
|
||||
border-color: rgba($article-caution-base, .4)
|
||||
border-color: rgba($article-caution-base, .4) !important
|
||||
}
|
||||
|
||||
///////////////////////////////// Scrollbars /////////////////////////////////
|
||||
|
|
|
@ -69,7 +69,7 @@
|
|||
background: $article-important-code-bg};
|
||||
}
|
||||
hr, .expand {
|
||||
border-color: rgba($article-important-base, .4)
|
||||
border-color: rgba($article-important-base, .4) !important;
|
||||
}
|
||||
|
||||
///////////////////////////////// Scrollbars /////////////////////////////////
|
||||
|
|
|
@ -67,7 +67,7 @@
|
|||
background: $article-note-code-bg};
|
||||
}
|
||||
hr, .expand {
|
||||
border-color: rgba($article-note-base, .4)
|
||||
border-color: rgba($article-note-base, .4) !important;
|
||||
}
|
||||
|
||||
///////////////////////////////// Scrollbars /////////////////////////////////
|
||||
|
|
|
@ -60,7 +60,7 @@
|
|||
}
|
||||
}
|
||||
hr, .expand {
|
||||
border-color: rgba($article-tip-base, .4)
|
||||
border-color: rgba($article-tip-base, .4) !important;
|
||||
}
|
||||
|
||||
///////////////////////////////// Scrollbars /////////////////////////////////
|
||||
|
|
|
@ -55,7 +55,7 @@
|
|||
background: $article-warning-code-bg};
|
||||
}
|
||||
hr, .expand {
|
||||
border-color: rgba($article-warning-base, .4)
|
||||
border-color: rgba($article-warning-base, .4) !important;
|
||||
}
|
||||
|
||||
///////////////////////////////// Scrollbars /////////////////////////////////
|
||||
|
|
|
@ -10,12 +10,15 @@ menu:
|
|||
weight: 305
|
||||
---
|
||||
|
||||
InfluxDB's SQL implementation supports time and date functions that are useful when working with time series data.
|
||||
InfluxDB's SQL implementation supports time and date functions that are useful
|
||||
when working with time series data.
|
||||
|
||||
- [current_date](#current_date)
|
||||
- [current_time](#current_time)
|
||||
- [date_bin](#date_bin)
|
||||
- [date_bin_gapfill](#date_bin_gapfill)
|
||||
- [date_bin_wallclock](#date_bin_wallclock)
|
||||
- [date_bin_wallclock_gapfill](#date_bin_wallclock_gapfill)
|
||||
- [date_trunc](#date_trunc)
|
||||
- [datetrunc](#datetrunc)
|
||||
- [date_part](#date_part)
|
||||
|
@ -136,26 +139,25 @@ date_bin(interval, expression[, origin_timestamp])
|
|||
|
||||
##### Arguments:
|
||||
|
||||
- **interval**: Bin interval.
|
||||
- **interval**: Bin interval. Supports the following interval units:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
- months
|
||||
- years
|
||||
- century
|
||||
|
||||
- **expression**: Time expression to operate on.
|
||||
Can be a constant, column, or function.
|
||||
- **origin_timestamp**: Starting point used to determine bin boundaries.
|
||||
_Default is the Unix epoch._
|
||||
|
||||
The following intervals are supported:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
- months
|
||||
- years
|
||||
- century
|
||||
|
||||
{{< expand-wrapper >}}
|
||||
{{% expand "View `date_bin` query example" %}}
|
||||
|
||||
|
@ -196,7 +198,7 @@ and null values in aggregate columns.
|
|||
|
||||
Use `date_bin_gapfill` with [`interpolate`](/influxdb/cloud-dedicated/reference/sql/functions/misc/#interpolate)
|
||||
or [`locf`](/influxdb/cloud-dedicated/reference/sql/functions/misc/#locf) to
|
||||
[fill gaps in data]()
|
||||
[fill gaps in data](/influxdb/cloud-dedicated/query-data/sql/fill-gaps/)
|
||||
at specified time intervals.
|
||||
|
||||
```sql
|
||||
|
@ -210,42 +212,36 @@ in the `WHERE` clause.
|
|||
|
||||
##### Arguments:
|
||||
|
||||
- **interval**: Bin interval.
|
||||
- **interval**: Bin interval. Supports the following interval units:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
- months
|
||||
- years
|
||||
- century
|
||||
|
||||
- **expression**: Time expression to operate on.
|
||||
Can be a constant, column, or function.
|
||||
- **origin_timestamp**: Starting point used to determine bin boundaries.
|
||||
_Default is the Unix epoch._
|
||||
|
||||
The following intervals are supported:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
- months
|
||||
- years
|
||||
- century
|
||||
|
||||
##### Related functions
|
||||
|
||||
[interpolate](/influxdb/cloud-dedicated/reference/sql/functions/misc/#interpolate),
|
||||
[locf](/influxdb/cloud-dedicated/reference/sql/functions/misc/#locf)
|
||||
|
||||
{{< expand-wrapper >}}
|
||||
{{% expand "View `date_bin_gapfill` query examples" %}}
|
||||
{{% expand "Use `date_bin_gapfill` to insert rows when no rows exists" %}}
|
||||
|
||||
_The following examples use the sample data set provided in the
|
||||
_The following example uses the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/cloud-dedicated/get-started/write/#construct-line-protocol)._
|
||||
|
||||
- [Use date_bin_gapfill to insert rows when no rows exists](#use-date_bin_gapfill-to-insert-rows-when-no-rows-exists)
|
||||
- [Use date_bin_gapfill to fill gaps in data](#use-date_bin_gapfill-to-fill-gaps-in-data)
|
||||
|
||||
#### Use date_bin_gapfill to insert rows when no rows exists
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
|
@ -274,12 +270,16 @@ GROUP BY _time, room
|
|||
| 2022-01-01T10:00:00Z | Living Room | 21.8 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
{{% /expand %}}
|
||||
|
||||
#### Use date_bin_gapfill to fill gaps in data
|
||||
{{% expand "Use `date_bin_gapfill` to fill gaps in data" %}}
|
||||
|
||||
Use `interpolate` and `locf` to fill the null values in rows inserted by
|
||||
`date_bin_gapfill`.
|
||||
|
||||
_The following examples use the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/cloud-dedicated/get-started/write/#construct-line-protocol)._
|
||||
|
||||
{{< tabs-wrapper >}}
|
||||
{{% tabs "small" %}}
|
||||
[interpolate](#)
|
||||
|
@ -360,6 +360,338 @@ GROUP BY _time, room
|
|||
{{% /expand %}}
|
||||
{{< /expand-wrapper >}}
|
||||
|
||||
## date_bin_wallclock
|
||||
|
||||
Calculates time intervals using the timezone of a specified time value and
|
||||
returns the start of the interval nearest to the specified timestamp.
|
||||
Use `date_bin_wallclock` to downsample time series data by grouping rows into
|
||||
time-based "bins" or "windows" that are based off "wall clock" times in a
|
||||
specific timezone and applying an aggregate or selector function to each window.
|
||||
|
||||
### Time zone shifts
|
||||
|
||||
Many regions use time zone shifts (such as daylight saving time (DST)).
|
||||
If a wall clock time bin starts at a time that does not exist in the specified
|
||||
time zone, the timestamp is adjusted to the time that is the same offset from
|
||||
the start of the day in that time zone.
|
||||
|
||||
If a wall clock time represents an ambiguous time in the region then the
|
||||
behavior depends on the size of the specified interval. If the interval is
|
||||
larger than the difference between the two possible timestamps, then the earlier
|
||||
timestamp is used. Otherwise, the function uses the timestamp that matches the
|
||||
UTC offset of the input timestamp.
|
||||
|
||||
```sql
|
||||
date_bin_wallclock(interval, expression[, origin_timestamp])
|
||||
```
|
||||
|
||||
##### Arguments:
|
||||
|
||||
- **interval**: Bin interval. Supports the following interval units:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
|
||||
> [!Note]
|
||||
> `date_bin_wallclock` does _not_ support month-, year-, or century-based intervals.
|
||||
|
||||
- **expression**: Time expression to operate on.
|
||||
Can be a constant, column, or function.
|
||||
The output timestamp uses the time zone from this time expression.
|
||||
- **origin_timestamp**: Starting point used to determine bin boundaries.
|
||||
This must be a "wall clock" timestamp (no time zone).
|
||||
_Default is the Unix epoch._
|
||||
|
||||
> [!Important]
|
||||
>
|
||||
> #### Avoid bins in time zone discontinuities
|
||||
>
|
||||
> [Time zone shifts](#time-zone-shifts) result in *discontinuities*–breaks
|
||||
> in the continuity of time intervals (losing an hour or gaining an hour)–that
|
||||
> can result in unexpected timestamps when using `date_bin_wallclock`.
|
||||
> Avoid using an `interval` and `origin_timestamp` combination that results in a
|
||||
> bin falling inside a time discontinuity.
|
||||
>
|
||||
> As a general rule, use either the default `origin_timestamp` or an origin
|
||||
> timestamp with an offset relative to the Unix epoch that is equal to your
|
||||
> specified `interval`.
|
||||
>
|
||||
> {{< expand-wrapper >}}
|
||||
{{% expand "View time zone discontinuity example" %}}
|
||||
|
||||
The following query illustrates how two timestamps, only one minute apart,
|
||||
result in timestamps two hours apart when binned across a daylight saving
|
||||
boundary:
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
tz('2020-10-25T02:29:00+01:00', 'Europe/Paris') AS original_time,
|
||||
date_bin_wallclock(
|
||||
INTERVAL '1 hour',
|
||||
tz('2020-10-25T02:29:00+01:00', 'Europe/Paris'),
|
||||
'1970-01-01T00:30:00'
|
||||
) AT TIME ZONE 'UTC' AS utc_bin_time
|
||||
UNION
|
||||
SELECT
|
||||
tz('2020-10-25T02:30:00+01:00', 'Europe/Paris') AS original_time,
|
||||
date_bin_wallclock(
|
||||
INTERVAL '1 hour',
|
||||
tz('2020-10-25T02:30:00+01:00', 'Europe/Paris'),
|
||||
'1970-01-01T00:30:00'
|
||||
) AT TIME ZONE 'UTC' AS utc_bin_time
|
||||
ORDER BY original_time;
|
||||
```
|
||||
|
||||
| original_time | utc_bin_time |
|
||||
| :------------------------ | :------------------- |
|
||||
| 2020-10-25T02:29:00+01:00 | 2020-10-24T23:30:00Z |
|
||||
| 2020-10-25T02:30:00+01:00 | 2020-10-25T01:30:00Z |
|
||||
|
||||
{{% /expand %}}
|
||||
{{< /expand-wrapper >}}
|
||||
|
||||
{{< expand-wrapper >}}
|
||||
{{% expand "View `date_bin_wallclock` query example" %}}
|
||||
|
||||
The following query uses the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/cloud-dedicated/get-started/write/#construct-line-protocol)
|
||||
and returns the 12-hour average temperature for each room using times in the
|
||||
`America/Los_Angeles` time zone.
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
date_bin_wallclock(INTERVAL '12 hours', tz(time, 'America/Los_Angeles')) AS time,
|
||||
room,
|
||||
avg(temp) AS avg_temp
|
||||
FROM home
|
||||
WHERE
|
||||
time >= '2022-01-01T08:00:00Z'
|
||||
AND time <= '2022-01-01T20:00:00Z'
|
||||
GROUP BY 1, room
|
||||
```
|
||||
|
||||
| time | room | avg_temp |
|
||||
| :------------------------ | :---------- | -----------------: |
|
||||
| 2022-01-01T00:00:00-08:00 | Kitchen | 22.61666666666667 |
|
||||
| 2022-01-01T12:00:00-08:00 | Kitchen | 22.7 |
|
||||
| 2022-01-01T00:00:00-08:00 | Living Room | 22.166666666666668 |
|
||||
| 2022-01-01T12:00:00-08:00 | Living Room | 22.2 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
|
||||
{{% /expand %}}
|
||||
{{< /expand-wrapper >}}
|
||||
|
||||
## date_bin_wallclock_gapfill
|
||||
|
||||
Calculates time intervals using the timezone of a specified time value and
|
||||
returns the start of the interval nearest to the specified timestamp.
|
||||
If no rows exist in a time interval, a new row is inserted with a `time` value
|
||||
set to the interval start time, all columns in the `GROUP BY` clause populated,
|
||||
and null values in aggregate columns.
|
||||
|
||||
Use `date_bin_wallclock_gapfill` with [`interpolate`](/influxdb/cloud-dedicated/reference/sql/functions/misc/#interpolate)
|
||||
or [`locf`](/influxdb/cloud-dedicated/reference/sql/functions/misc/#locf) to
|
||||
[fill gaps in data](/influxdb/cloud-dedicated/query-data/sql/fill-gaps/)
|
||||
at specified time intervals in a specified time zone.
|
||||
|
||||
### Time zone shifts
|
||||
|
||||
Many regions use time zone shifts (such as daylight saving time (DST)).
|
||||
If a wall clock time bin starts at a time that does not exist in the specified
|
||||
time zone, the timestamp is adjusted to the time that is the same offset from
|
||||
the start of the day in that time zone.
|
||||
|
||||
If a wall clock time represents an ambiguous time in the region then the
|
||||
behavior depends on the size of the specified interval. If the interval is
|
||||
larger than the difference between the two possible timestamps, then the earlier
|
||||
timestamp is used. Otherwise, the function uses the timestamp that matches the
|
||||
UTC offset of the input timestamp.
|
||||
|
||||
```sql
|
||||
date_bin_wallclock_gapfill(interval, expression[, origin_timestamp])
|
||||
```
|
||||
|
||||
{{% note %}}
|
||||
`date_bin_wallclock_gapfill` requires [time bounds](/influxdb/cloud-dedicated/query-data/sql/basic-query/#query-data-within-time-boundaries)
|
||||
in the `WHERE` clause.
|
||||
{{% /note %}}
|
||||
|
||||
##### Arguments:
|
||||
|
||||
- **interval**: Bin interval. Supports the following interval units:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
|
||||
> [!Note]
|
||||
> `date_bin_wallclock_gapfill` does _not_ support month-, year-, or century-based intervals.
|
||||
|
||||
- **expression**: Time expression to operate on.
|
||||
Can be a constant, column, or function.
|
||||
The output timestamp uses the time zone from this time expression.
|
||||
- **origin_timestamp**: Starting point used to determine bin boundaries.
|
||||
This must be a "wall clock" timestamp (no time zone).
|
||||
_Default is the Unix epoch._
|
||||
|
||||
> [!Important]
|
||||
>
|
||||
> #### Avoid bins in time zone discontinuities
|
||||
>
|
||||
> [Time zone shifts](#time-zone-shifts) result in *discontinuities*–breaks
|
||||
> in the continuity of time intervals (losing an hour or gaining an hour)–that
|
||||
> can result in unexpected timestamps when using `date_bin_wallclock_gapfill`.
|
||||
> Avoid using an `interval` and `origin_timestamp` combination that results in a
|
||||
> bin falling inside a time discontinuity.
|
||||
>
|
||||
> As a general rule, use either the default `origin_timestamp` or an origin
|
||||
> timestamp with an offset relative to the Unix epoch that is equal to your
|
||||
> specified `interval`.
|
||||
>
|
||||
> [View time zone discontinuity example](#view-time-zone-discontinuity-example)
|
||||
|
||||
##### Related functions
|
||||
|
||||
[interpolate](/influxdb/cloud-dedicated/reference/sql/functions/misc/#interpolate),
|
||||
[locf](/influxdb/cloud-dedicated/reference/sql/functions/misc/#locf)
|
||||
|
||||
{{< expand-wrapper >}}
|
||||
{{% expand "Use `date_bin_wallclock_gapfill` to insert rows when no rows exists" %}}
|
||||
|
||||
_The following example uses the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/cloud-dedicated/get-started/write/#construct-line-protocol)._
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
date_bin_wallclock_gapfill(INTERVAL '30 minutes', tz(time, 'America/Los_Angeles')) as time,
|
||||
room,
|
||||
avg(temp) as temp
|
||||
FROM home
|
||||
WHERE
|
||||
time >= '2022-01-01T08:00:00Z'
|
||||
AND time <= '2022-01-01T10:00:00Z'
|
||||
GROUP BY 1, room
|
||||
```
|
||||
|
||||
| time | room | temp |
|
||||
| :------------------------ | :---------- | ---: |
|
||||
| 2022-01-01T00:00:00-08:00 | Kitchen | 21 |
|
||||
| 2022-01-01T00:30:00-08:00 | Kitchen | |
|
||||
| 2022-01-01T01:00:00-08:00 | Kitchen | 23 |
|
||||
| 2022-01-01T01:30:00-08:00 | Kitchen | |
|
||||
| 2022-01-01T02:00:00-08:00 | Kitchen | 22.7 |
|
||||
| 2022-01-01T00:00:00-08:00 | Living Room | 21.1 |
|
||||
| 2022-01-01T00:30:00-08:00 | Living Room | |
|
||||
| 2022-01-01T01:00:00-08:00 | Living Room | 21.4 |
|
||||
| 2022-01-01T01:30:00-08:00 | Living Room | |
|
||||
| 2022-01-01T02:00:00-08:00 | Living Room | 21.8 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
{{% /expand %}}
|
||||
|
||||
{{% expand "Use `date_bin_wallclock_gapfill` to fill gaps in data" %}}
|
||||
|
||||
Use `interpolate` and `locf` to fill the null values in rows inserted by
|
||||
`date_bin_wallclock_gapfill`.
|
||||
|
||||
_The following examples use the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/cloud-dedicated/get-started/write/#construct-line-protocol)._
|
||||
|
||||
{{< tabs-wrapper >}}
|
||||
{{% tabs "small" %}}
|
||||
[interpolate](#)
|
||||
[locf](#)
|
||||
{{% /tabs %}}
|
||||
{{% tab-content %}}
|
||||
|
||||
The example below uses [`interpolate`](/influxdb/cloud-dedicated/reference/sql/functions/misc/#interpolate)
|
||||
to fill null values by interpolating values between non-null values.
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
date_bin_wallclock_gapfill(INTERVAL '30 minutes', tz(time, 'America/Los_Angeles')) as time,
|
||||
room,
|
||||
interpolate(avg(temp))
|
||||
FROM home
|
||||
WHERE
|
||||
time >= '2022-01-01T08:00:00Z'
|
||||
AND time <= '2022-01-01T10:00:00Z'
|
||||
GROUP BY 1, room
|
||||
```
|
||||
|
||||
| time | room | interpolate(avg(home.temp)) |
|
||||
| :------------------------ | :---------- | --------------------------: |
|
||||
| 2022-01-01T00:00:00-08:00 | Kitchen | 21 |
|
||||
| 2022-01-01T00:30:00-08:00 | Kitchen | 22 |
|
||||
| 2022-01-01T01:00:00-08:00 | Kitchen | 23 |
|
||||
| 2022-01-01T01:30:00-08:00 | Kitchen | 22.85 |
|
||||
| 2022-01-01T02:00:00-08:00 | Kitchen | 22.7 |
|
||||
| 2022-01-01T00:00:00-08:00 | Living Room | 21.1 |
|
||||
| 2022-01-01T00:30:00-08:00 | Living Room | 21.25 |
|
||||
| 2022-01-01T01:00:00-08:00 | Living Room | 21.4 |
|
||||
| 2022-01-01T01:30:00-08:00 | Living Room | 21.6 |
|
||||
| 2022-01-01T02:00:00-08:00 | Living Room | 21.8 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
|
||||
{{% /tab-content %}}
|
||||
{{% tab-content %}}
|
||||
|
||||
The example below uses [`locf`](/influxdb/cloud-dedicated/reference/sql/functions/misc/#locf)
|
||||
to fill null values by carrying the last observed value forward.
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
date_bin_wallclock_gapfill(INTERVAL '30 minutes', tz(time, 'America/Los_Angeles')) as time,
|
||||
room,
|
||||
locf(avg(temp))
|
||||
FROM home
|
||||
WHERE
|
||||
time >= '2022-01-01T08:00:00Z'
|
||||
AND time <= '2022-01-01T10:00:00Z'
|
||||
GROUP BY 1, room
|
||||
```
|
||||
|
||||
| time | room | locf(avg(home.temp)) |
|
||||
| :------------------------ | :---------- | -------------------: |
|
||||
| 2022-01-01T00:00:00-08:00 | Kitchen | 21 |
|
||||
| 2022-01-01T00:30:00-08:00 | Kitchen | 21 |
|
||||
| 2022-01-01T01:00:00-08:00 | Kitchen | 23 |
|
||||
| 2022-01-01T01:30:00-08:00 | Kitchen | 23 |
|
||||
| 2022-01-01T02:00:00-08:00 | Kitchen | 22.7 |
|
||||
| 2022-01-01T00:00:00-08:00 | Living Room | 21.1 |
|
||||
| 2022-01-01T00:30:00-08:00 | Living Room | 21.1 |
|
||||
| 2022-01-01T01:00:00-08:00 | Living Room | 21.4 |
|
||||
| 2022-01-01T01:30:00-08:00 | Living Room | 21.4 |
|
||||
| 2022-01-01T02:00:00-08:00 | Living Room | 21.8 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
|
||||
{{% /tab-content %}}
|
||||
{{< /tabs-wrapper >}}
|
||||
|
||||
{{% /expand %}}
|
||||
{{< /expand-wrapper >}}
|
||||
|
||||
## date_trunc
|
||||
|
||||
|
@ -740,7 +1072,7 @@ SELECT
|
|||
|
||||
Converts a timestamp with a timezone to a timestamp without a timezone
|
||||
(no offset or timezone information). This function accounts for time shifts
|
||||
like Daylight Saving Time (DST) or British Summer Time (BST).
|
||||
like daylight saving time (DST).
|
||||
|
||||
{{% note %}}
|
||||
Use `to_local_time()` with [`date_bin()`](#date_bin) and
|
||||
|
@ -1120,19 +1452,24 @@ SELECT tz(time, 'Australia/Sydney') AS time_tz, time FROM home ORDER BY time LIM
|
|||
{{< /expand-wrapper >}}
|
||||
|
||||
##### 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')
|
||||
|
@ -1140,18 +1477,22 @@ differ when the input timestamp **does not** have a timezone.
|
|||
-- 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
|
||||
|
|
|
@ -10,12 +10,15 @@ menu:
|
|||
weight: 305
|
||||
---
|
||||
|
||||
InfluxDB's SQL implementation supports time and date functions that are useful when working with time series data.
|
||||
InfluxDB's SQL implementation supports time and date functions that are useful
|
||||
when working with time series data.
|
||||
|
||||
- [current_date](#current_date)
|
||||
- [current_time](#current_time)
|
||||
- [date_bin](#date_bin)
|
||||
- [date_bin_gapfill](#date_bin_gapfill)
|
||||
- [date_bin_wallclock](#date_bin_wallclock)
|
||||
- [date_bin_wallclock_gapfill](#date_bin_wallclock_gapfill)
|
||||
- [date_trunc](#date_trunc)
|
||||
- [datetrunc](#datetrunc)
|
||||
- [date_part](#date_part)
|
||||
|
@ -128,7 +131,7 @@ 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, 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`.
|
||||
|
||||
```sql
|
||||
date_bin(interval, expression[, origin_timestamp])
|
||||
|
@ -136,26 +139,25 @@ date_bin(interval, expression[, origin_timestamp])
|
|||
|
||||
##### Arguments:
|
||||
|
||||
- **interval**: Bin interval.
|
||||
- **interval**: Bin interval. Supports the following interval units:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
- months
|
||||
- years
|
||||
- century
|
||||
|
||||
- **expression**: Time expression to operate on.
|
||||
Can be a constant, column, or function.
|
||||
- **origin_timestamp**: Starting point used to determine bin boundaries.
|
||||
_Default is the Unix epoch._
|
||||
|
||||
The following intervals are supported:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
- months
|
||||
- years
|
||||
- century
|
||||
|
||||
{{< expand-wrapper >}}
|
||||
{{% expand "View `date_bin` query example" %}}
|
||||
|
||||
|
@ -163,7 +165,7 @@ The following query returns the daily average of water levels in the queried tim
|
|||
|
||||
```sql
|
||||
SELECT
|
||||
date_bin(INTERVAL '1 day', time, TIMESTAMP '1970-01-01 00:00:00Z') AS _time,
|
||||
date_bin(INTERVAL '1 day', time, TIMESTAMP '1970-01-01 00:00:00Z') AS time,
|
||||
avg("water_level") AS water_level_avg
|
||||
FROM "h2o_feet"
|
||||
WHERE
|
||||
|
@ -196,7 +198,7 @@ and null values in aggregate columns.
|
|||
|
||||
Use `date_bin_gapfill` with [`interpolate`](/influxdb/cloud-serverless/reference/sql/functions/misc/#interpolate)
|
||||
or [`locf`](/influxdb/cloud-serverless/reference/sql/functions/misc/#locf) to
|
||||
[fill gaps in data]()
|
||||
[fill gaps in data](/influxdb/cloud-serverless/query-data/sql/fill-gaps/)
|
||||
at specified time intervals.
|
||||
|
||||
```sql
|
||||
|
@ -210,42 +212,36 @@ in the `WHERE` clause.
|
|||
|
||||
##### Arguments:
|
||||
|
||||
- **interval**: Bin interval.
|
||||
- **interval**: Bin interval. Supports the following interval units:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
- months
|
||||
- years
|
||||
- century
|
||||
|
||||
- **expression**: Time expression to operate on.
|
||||
Can be a constant, column, or function.
|
||||
- **origin_timestamp**: Starting point used to determine bin boundaries.
|
||||
_Default is the Unix epoch._
|
||||
|
||||
The following intervals are supported:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
- months
|
||||
- years
|
||||
- century
|
||||
|
||||
##### Related functions
|
||||
|
||||
[interpolate](/influxdb/cloud-serverless/reference/sql/functions/misc/#interpolate),
|
||||
[locf](/influxdb/cloud-serverless/reference/sql/functions/misc/#locf)
|
||||
|
||||
{{< expand-wrapper >}}
|
||||
{{% expand "View `date_bin_gapfill` query examples" %}}
|
||||
{{% expand "Use `date_bin_gapfill` to insert rows when no rows exists" %}}
|
||||
|
||||
_The following examples use the sample data set provided in the
|
||||
_The following example uses the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/cloud-serverless/get-started/write/#construct-line-protocol)._
|
||||
|
||||
- [Use date_bin_gapfill to insert rows when no rows exists](#use-date_bin_gapfill-to-insert-rows-when-no-rows-exists)
|
||||
- [Use date_bin_gapfill to fill gaps in data](#use-date_bin_gapfill-to-fill-gaps-in-data)
|
||||
|
||||
#### Use date_bin_gapfill to insert rows when no rows exists
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
|
@ -274,12 +270,16 @@ GROUP BY _time, room
|
|||
| 2022-01-01T10:00:00Z | Living Room | 21.8 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
{{% /expand %}}
|
||||
|
||||
#### Use date_bin_gapfill to fill gaps in data
|
||||
{{% expand "Use `date_bin_gapfill` to fill gaps in data" %}}
|
||||
|
||||
Use `interpolate` and `locf` to fill the null values in rows inserted by
|
||||
`date_bin_gapfill`.
|
||||
|
||||
_The following examples use the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/cloud-serverless/get-started/write/#construct-line-protocol)._
|
||||
|
||||
{{< tabs-wrapper >}}
|
||||
{{% tabs "small" %}}
|
||||
[interpolate](#)
|
||||
|
@ -360,6 +360,338 @@ GROUP BY _time, room
|
|||
{{% /expand %}}
|
||||
{{< /expand-wrapper >}}
|
||||
|
||||
## date_bin_wallclock
|
||||
|
||||
Calculates time intervals using the timezone of a specified time value and
|
||||
returns the start of the interval nearest to the specified timestamp.
|
||||
Use `date_bin_wallclock` to downsample time series data by grouping rows into
|
||||
time-based "bins" or "windows" that are based off "wall clock" times in a
|
||||
specific timezone and applying an aggregate or selector function to each window.
|
||||
|
||||
### Time zone shifts
|
||||
|
||||
Many regions use time zone shifts (such as daylight saving time (DST)).
|
||||
If a wall clock time bin starts at a time that does not exist in the specified
|
||||
time zone, the timestamp is adjusted to the time that is the same offset from
|
||||
the start of the day in that time zone.
|
||||
|
||||
If a wall clock time represents an ambiguous time in the region then the
|
||||
behavior depends on the size of the specified interval. If the interval is
|
||||
larger than the difference between the two possible timestamps, then the earlier
|
||||
timestamp is used. Otherwise, the function uses the timestamp that matches the
|
||||
UTC offset of the input timestamp.
|
||||
|
||||
```sql
|
||||
date_bin_wallclock(interval, expression[, origin_timestamp])
|
||||
```
|
||||
|
||||
##### Arguments:
|
||||
|
||||
- **interval**: Bin interval. Supports the following interval units:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
|
||||
> [!Note]
|
||||
> `date_bin_wallclock` does _not_ support month-, year-, or century-based intervals.
|
||||
|
||||
- **expression**: Time expression to operate on.
|
||||
Can be a constant, column, or function.
|
||||
The output timestamp uses the time zone from this time expression.
|
||||
- **origin_timestamp**: Starting point used to determine bin boundaries.
|
||||
This must be a "wall clock" timestamp (no time zone).
|
||||
_Default is the Unix epoch._
|
||||
|
||||
> [!Important]
|
||||
>
|
||||
> #### Avoid bins in time zone discontinuities
|
||||
>
|
||||
> [Time zone shifts](#time-zone-shifts) result in *discontinuities*–breaks
|
||||
> in the continuity of time intervals (losing an hour or gaining an hour)–that
|
||||
> can result in unexpected timestamps when using `date_bin_wallclock`.
|
||||
> Avoid using an `interval` and `origin_timestamp` combination that results in a
|
||||
> bin falling inside a time discontinuity.
|
||||
>
|
||||
> As a general rule, use either the default `origin_timestamp` or an origin
|
||||
> timestamp with an offset relative to the Unix epoch that is equal to your
|
||||
> specified `interval`.
|
||||
>
|
||||
> {{< expand-wrapper >}}
|
||||
{{% expand "View time zone discontinuity example" %}}
|
||||
|
||||
The following query illustrates how two timestamps, only one minute apart,
|
||||
result in timestamps two hours apart when binned across a daylight saving
|
||||
boundary:
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
tz('2020-10-25T02:29:00+01:00', 'Europe/Paris') AS original_time,
|
||||
date_bin_wallclock(
|
||||
INTERVAL '1 hour',
|
||||
tz('2020-10-25T02:29:00+01:00', 'Europe/Paris'),
|
||||
'1970-01-01T00:30:00'
|
||||
) AT TIME ZONE 'UTC' AS utc_bin_time
|
||||
UNION
|
||||
SELECT
|
||||
tz('2020-10-25T02:30:00+01:00', 'Europe/Paris') AS original_time,
|
||||
date_bin_wallclock(
|
||||
INTERVAL '1 hour',
|
||||
tz('2020-10-25T02:30:00+01:00', 'Europe/Paris'),
|
||||
'1970-01-01T00:30:00'
|
||||
) AT TIME ZONE 'UTC' AS utc_bin_time
|
||||
ORDER BY original_time;
|
||||
```
|
||||
|
||||
| original_time | utc_bin_time |
|
||||
| :------------------------ | :------------------- |
|
||||
| 2020-10-25T02:29:00+01:00 | 2020-10-24T23:30:00Z |
|
||||
| 2020-10-25T02:30:00+01:00 | 2020-10-25T01:30:00Z |
|
||||
|
||||
{{% /expand %}}
|
||||
{{< /expand-wrapper >}}
|
||||
|
||||
{{< expand-wrapper >}}
|
||||
{{% expand "View `date_bin_wallclock` query example" %}}
|
||||
|
||||
The following query uses the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/cloud-serverless/get-started/write/#construct-line-protocol)
|
||||
and returns the 12-hour average temperature for each room using times in the
|
||||
`America/Los_Angeles` time zone.
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
date_bin_wallclock(INTERVAL '12 hours', tz(time, 'America/Los_Angeles')) AS time,
|
||||
room,
|
||||
avg(temp) AS avg_temp
|
||||
FROM home
|
||||
WHERE
|
||||
time >= '2022-01-01T08:00:00Z'
|
||||
AND time <= '2022-01-01T20:00:00Z'
|
||||
GROUP BY 1, room
|
||||
```
|
||||
|
||||
| time | room | avg_temp |
|
||||
| :------------------------ | :---------- | -----------------: |
|
||||
| 2022-01-01T00:00:00-08:00 | Kitchen | 22.61666666666667 |
|
||||
| 2022-01-01T12:00:00-08:00 | Kitchen | 22.7 |
|
||||
| 2022-01-01T00:00:00-08:00 | Living Room | 22.166666666666668 |
|
||||
| 2022-01-01T12:00:00-08:00 | Living Room | 22.2 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
|
||||
{{% /expand %}}
|
||||
{{< /expand-wrapper >}}
|
||||
|
||||
## date_bin_wallclock_gapfill
|
||||
|
||||
Calculates time intervals using the timezone of a specified time value and
|
||||
returns the start of the interval nearest to the specified timestamp.
|
||||
If no rows exist in a time interval, a new row is inserted with a `time` value
|
||||
set to the interval start time, all columns in the `GROUP BY` clause populated,
|
||||
and null values in aggregate columns.
|
||||
|
||||
Use `date_bin_wallclock_gapfill` with [`interpolate`](/influxdb/cloud-serverless/reference/sql/functions/misc/#interpolate)
|
||||
or [`locf`](/influxdb/cloud-serverless/reference/sql/functions/misc/#locf) to
|
||||
[fill gaps in data](/influxdb/cloud-serverless/query-data/sql/fill-gaps/)
|
||||
at specified time intervals in a specified time zone.
|
||||
|
||||
### Time zone shifts
|
||||
|
||||
Many regions use time zone shifts (such as daylight saving time (DST)).
|
||||
If a wall clock time bin starts at a time that does not exist in the specified
|
||||
time zone, the timestamp is adjusted to the time that is the same offset from
|
||||
the start of the day in that time zone.
|
||||
|
||||
If a wall clock time represents an ambiguous time in the region then the
|
||||
behavior depends on the size of the specified interval. If the interval is
|
||||
larger than the difference between the two possible timestamps, then the earlier
|
||||
timestamp is used. Otherwise, the function uses the timestamp that matches the
|
||||
UTC offset of the input timestamp.
|
||||
|
||||
```sql
|
||||
date_bin_wallclock_gapfill(interval, expression[, origin_timestamp])
|
||||
```
|
||||
|
||||
{{% note %}}
|
||||
`date_bin_wallclock_gapfill` requires [time bounds](/influxdb/cloud-serverless/query-data/sql/basic-query/#query-data-within-time-boundaries)
|
||||
in the `WHERE` clause.
|
||||
{{% /note %}}
|
||||
|
||||
##### Arguments:
|
||||
|
||||
- **interval**: Bin interval. Supports the following interval units:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
|
||||
> [!Note]
|
||||
> `date_bin_wallclock_gapfill` does _not_ support month-, year-, or century-based intervals.
|
||||
|
||||
- **expression**: Time expression to operate on.
|
||||
Can be a constant, column, or function.
|
||||
The output timestamp uses the time zone from this time expression.
|
||||
- **origin_timestamp**: Starting point used to determine bin boundaries.
|
||||
This must be a "wall clock" timestamp (no time zone).
|
||||
_Default is the Unix epoch._
|
||||
|
||||
> [!Important]
|
||||
>
|
||||
> #### Avoid bins in time zone discontinuities
|
||||
>
|
||||
> [Time zone shifts](#time-zone-shifts) result in *discontinuities*–breaks
|
||||
> in the continuity of time intervals (losing an hour or gaining an hour)–that
|
||||
> can result in unexpected timestamps when using `date_bin_wallclock_gapfill`.
|
||||
> Avoid using an `interval` and `origin_timestamp` combination that results in a
|
||||
> bin falling inside a time discontinuity.
|
||||
>
|
||||
> As a general rule, use either the default `origin_timestamp` or an origin
|
||||
> timestamp with an offset relative to the Unix epoch that is equal to your
|
||||
> specified `interval`.
|
||||
>
|
||||
> [View time zone discontinuity example](#view-time-zone-discontinuity-example)
|
||||
|
||||
##### Related functions
|
||||
|
||||
[interpolate](/influxdb/cloud-serverless/reference/sql/functions/misc/#interpolate),
|
||||
[locf](/influxdb/cloud-serverless/reference/sql/functions/misc/#locf)
|
||||
|
||||
{{< expand-wrapper >}}
|
||||
{{% expand "Use `date_bin_wallclock_gapfill` to insert rows when no rows exists" %}}
|
||||
|
||||
_The following example uses the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/cloud-serverless/get-started/write/#construct-line-protocol)._
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
date_bin_wallclock_gapfill(INTERVAL '30 minutes', tz(time, 'America/Los_Angeles')) as time,
|
||||
room,
|
||||
avg(temp) as temp
|
||||
FROM home
|
||||
WHERE
|
||||
time >= '2022-01-01T08:00:00Z'
|
||||
AND time <= '2022-01-01T10:00:00Z'
|
||||
GROUP BY 1, room
|
||||
```
|
||||
|
||||
| time | room | temp |
|
||||
| :------------------------ | :---------- | ---: |
|
||||
| 2022-01-01T00:00:00-08:00 | Kitchen | 21 |
|
||||
| 2022-01-01T00:30:00-08:00 | Kitchen | |
|
||||
| 2022-01-01T01:00:00-08:00 | Kitchen | 23 |
|
||||
| 2022-01-01T01:30:00-08:00 | Kitchen | |
|
||||
| 2022-01-01T02:00:00-08:00 | Kitchen | 22.7 |
|
||||
| 2022-01-01T00:00:00-08:00 | Living Room | 21.1 |
|
||||
| 2022-01-01T00:30:00-08:00 | Living Room | |
|
||||
| 2022-01-01T01:00:00-08:00 | Living Room | 21.4 |
|
||||
| 2022-01-01T01:30:00-08:00 | Living Room | |
|
||||
| 2022-01-01T02:00:00-08:00 | Living Room | 21.8 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
{{% /expand %}}
|
||||
|
||||
{{% expand "Use `date_bin_wallclock_gapfill` to fill gaps in data" %}}
|
||||
|
||||
Use `interpolate` and `locf` to fill the null values in rows inserted by
|
||||
`date_bin_wallclock_gapfill`.
|
||||
|
||||
_The following examples use the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/cloud-serverless/get-started/write/#construct-line-protocol)._
|
||||
|
||||
{{< tabs-wrapper >}}
|
||||
{{% tabs "small" %}}
|
||||
[interpolate](#)
|
||||
[locf](#)
|
||||
{{% /tabs %}}
|
||||
{{% tab-content %}}
|
||||
|
||||
The example below uses [`interpolate`](/influxdb/cloud-serverless/reference/sql/functions/misc/#interpolate)
|
||||
to fill null values by interpolating values between non-null values.
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
date_bin_wallclock_gapfill(INTERVAL '30 minutes', tz(time, 'America/Los_Angeles')) as time,
|
||||
room,
|
||||
interpolate(avg(temp))
|
||||
FROM home
|
||||
WHERE
|
||||
time >= '2022-01-01T08:00:00Z'
|
||||
AND time <= '2022-01-01T10:00:00Z'
|
||||
GROUP BY 1, room
|
||||
```
|
||||
|
||||
| time | room | interpolate(avg(home.temp)) |
|
||||
| :------------------------ | :---------- | --------------------------: |
|
||||
| 2022-01-01T00:00:00-08:00 | Kitchen | 21 |
|
||||
| 2022-01-01T00:30:00-08:00 | Kitchen | 22 |
|
||||
| 2022-01-01T01:00:00-08:00 | Kitchen | 23 |
|
||||
| 2022-01-01T01:30:00-08:00 | Kitchen | 22.85 |
|
||||
| 2022-01-01T02:00:00-08:00 | Kitchen | 22.7 |
|
||||
| 2022-01-01T00:00:00-08:00 | Living Room | 21.1 |
|
||||
| 2022-01-01T00:30:00-08:00 | Living Room | 21.25 |
|
||||
| 2022-01-01T01:00:00-08:00 | Living Room | 21.4 |
|
||||
| 2022-01-01T01:30:00-08:00 | Living Room | 21.6 |
|
||||
| 2022-01-01T02:00:00-08:00 | Living Room | 21.8 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
|
||||
{{% /tab-content %}}
|
||||
{{% tab-content %}}
|
||||
|
||||
The example below uses [`locf`](/influxdb/cloud-serverless/reference/sql/functions/misc/#locf)
|
||||
to fill null values by carrying the last observed value forward.
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
date_bin_wallclock_gapfill(INTERVAL '30 minutes', tz(time, 'America/Los_Angeles')) as time,
|
||||
room,
|
||||
locf(avg(temp))
|
||||
FROM home
|
||||
WHERE
|
||||
time >= '2022-01-01T08:00:00Z'
|
||||
AND time <= '2022-01-01T10:00:00Z'
|
||||
GROUP BY 1, room
|
||||
```
|
||||
|
||||
| time | room | locf(avg(home.temp)) |
|
||||
| :------------------------ | :---------- | -------------------: |
|
||||
| 2022-01-01T00:00:00-08:00 | Kitchen | 21 |
|
||||
| 2022-01-01T00:30:00-08:00 | Kitchen | 21 |
|
||||
| 2022-01-01T01:00:00-08:00 | Kitchen | 23 |
|
||||
| 2022-01-01T01:30:00-08:00 | Kitchen | 23 |
|
||||
| 2022-01-01T02:00:00-08:00 | Kitchen | 22.7 |
|
||||
| 2022-01-01T00:00:00-08:00 | Living Room | 21.1 |
|
||||
| 2022-01-01T00:30:00-08:00 | Living Room | 21.1 |
|
||||
| 2022-01-01T01:00:00-08:00 | Living Room | 21.4 |
|
||||
| 2022-01-01T01:30:00-08:00 | Living Room | 21.4 |
|
||||
| 2022-01-01T02:00:00-08:00 | Living Room | 21.8 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
|
||||
{{% /tab-content %}}
|
||||
{{< /tabs-wrapper >}}
|
||||
|
||||
{{% /expand %}}
|
||||
{{< /expand-wrapper >}}
|
||||
|
||||
## date_trunc
|
||||
|
||||
|
@ -740,7 +1072,7 @@ SELECT
|
|||
|
||||
Converts a timestamp with a timezone to a timestamp without a timezone
|
||||
(no offset or timezone information). This function accounts for time shifts
|
||||
like Daylight Saving Time (DST) or British Summer Time (BST).
|
||||
like daylight saving time (DST).
|
||||
|
||||
{{% note %}}
|
||||
Use `to_local_time()` with [`date_bin()`](#date_bin) and
|
||||
|
@ -1120,19 +1452,24 @@ SELECT tz(time, 'Australia/Sydney') AS time_tz, time FROM home ORDER BY time LIM
|
|||
{{< /expand-wrapper >}}
|
||||
|
||||
##### 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')
|
||||
|
@ -1140,18 +1477,22 @@ differ when the input timestamp **does not** have a timezone.
|
|||
-- 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
|
||||
|
|
|
@ -10,12 +10,15 @@ menu:
|
|||
weight: 305
|
||||
---
|
||||
|
||||
InfluxDB's SQL implementation supports time and date functions that are useful when working with time series data.
|
||||
InfluxDB's SQL implementation supports time and date functions that are useful
|
||||
when working with time series data.
|
||||
|
||||
- [current_date](#current_date)
|
||||
- [current_time](#current_time)
|
||||
- [date_bin](#date_bin)
|
||||
- [date_bin_gapfill](#date_bin_gapfill)
|
||||
- [date_bin_wallclock](#date_bin_wallclock)
|
||||
- [date_bin_wallclock_gapfill](#date_bin_wallclock_gapfill)
|
||||
- [date_trunc](#date_trunc)
|
||||
- [datetrunc](#datetrunc)
|
||||
- [date_part](#date_part)
|
||||
|
@ -128,7 +131,7 @@ 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, 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`.
|
||||
|
||||
```sql
|
||||
date_bin(interval, expression[, origin_timestamp])
|
||||
|
@ -136,26 +139,25 @@ date_bin(interval, expression[, origin_timestamp])
|
|||
|
||||
##### Arguments:
|
||||
|
||||
- **interval**: Bin interval.
|
||||
- **interval**: Bin interval. Supports the following interval units:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
- months
|
||||
- years
|
||||
- century
|
||||
|
||||
- **expression**: Time expression to operate on.
|
||||
Can be a constant, column, or function.
|
||||
- **origin_timestamp**: Starting point used to determine bin boundaries.
|
||||
_Default is the Unix epoch._
|
||||
|
||||
The following intervals are supported:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
- months
|
||||
- years
|
||||
- century
|
||||
|
||||
{{< expand-wrapper >}}
|
||||
{{% expand "View `date_bin` query example" %}}
|
||||
|
||||
|
@ -196,7 +198,7 @@ and null values in aggregate columns.
|
|||
|
||||
Use `date_bin_gapfill` with [`interpolate`](/influxdb/clustered/reference/sql/functions/misc/#interpolate)
|
||||
or [`locf`](/influxdb/clustered/reference/sql/functions/misc/#locf) to
|
||||
[fill gaps in data]()
|
||||
[fill gaps in data](/influxdb/clustered/query-data/sql/fill-gaps/)
|
||||
at specified time intervals.
|
||||
|
||||
```sql
|
||||
|
@ -210,42 +212,36 @@ in the `WHERE` clause.
|
|||
|
||||
##### Arguments:
|
||||
|
||||
- **interval**: Bin interval.
|
||||
- **interval**: Bin interval. Supports the following interval units:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
- months
|
||||
- years
|
||||
- century
|
||||
|
||||
- **expression**: Time expression to operate on.
|
||||
Can be a constant, column, or function.
|
||||
- **origin_timestamp**: Starting point used to determine bin boundaries.
|
||||
_Default is the Unix epoch._
|
||||
|
||||
The following intervals are supported:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
- months
|
||||
- years
|
||||
- century
|
||||
|
||||
##### Related functions
|
||||
|
||||
[interpolate](/influxdb/clustered/reference/sql/functions/misc/#interpolate),
|
||||
[locf](/influxdb/clustered/reference/sql/functions/misc/#locf)
|
||||
|
||||
{{< expand-wrapper >}}
|
||||
{{% expand "View `date_bin_gapfill` query examples" %}}
|
||||
{{% expand "Use `date_bin_gapfill` to insert rows when no rows exists" %}}
|
||||
|
||||
_The following examples use the sample data set provided in the
|
||||
_The following example uses the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/clustered/get-started/write/#construct-line-protocol)._
|
||||
|
||||
- [Use date_bin_gapfill to insert rows when no rows exists](#use-date_bin_gapfill-to-insert-rows-when-no-rows-exists)
|
||||
- [Use date_bin_gapfill to fill gaps in data](#use-date_bin_gapfill-to-fill-gaps-in-data)
|
||||
|
||||
#### Use date_bin_gapfill to insert rows when no rows exists
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
|
@ -274,12 +270,16 @@ GROUP BY _time, room
|
|||
| 2022-01-01T10:00:00Z | Living Room | 21.8 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
{{% /expand %}}
|
||||
|
||||
#### Use date_bin_gapfill to fill gaps in data
|
||||
{{% expand "Use `date_bin_gapfill` to fill gaps in data" %}}
|
||||
|
||||
Use `interpolate` and `locf` to fill the null values in rows inserted by
|
||||
`date_bin_gapfill`.
|
||||
|
||||
_The following examples use the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/clustered/get-started/write/#construct-line-protocol)._
|
||||
|
||||
{{< tabs-wrapper >}}
|
||||
{{% tabs "small" %}}
|
||||
[interpolate](#)
|
||||
|
@ -360,6 +360,338 @@ GROUP BY _time, room
|
|||
{{% /expand %}}
|
||||
{{< /expand-wrapper >}}
|
||||
|
||||
## date_bin_wallclock
|
||||
|
||||
Calculates time intervals using the timezone of a specified time value and
|
||||
returns the start of the interval nearest to the specified timestamp.
|
||||
Use `date_bin_wallclock` to downsample time series data by grouping rows into
|
||||
time-based "bins" or "windows" that are based off "wall clock" times in a
|
||||
specific timezone and applying an aggregate or selector function to each window.
|
||||
|
||||
### Time zone shifts
|
||||
|
||||
Many regions use time zone shifts (such as daylight saving time (DST)).
|
||||
If a wall clock time bin starts at a time that does not exist in the specified
|
||||
time zone, the timestamp is adjusted to the time that is the same offset from
|
||||
the start of the day in that time zone.
|
||||
|
||||
If a wall clock time represents an ambiguous time in the region then the
|
||||
behavior depends on the size of the specified interval. If the interval is
|
||||
larger than the difference between the two possible timestamps, then the earlier
|
||||
timestamp is used. Otherwise, the function uses the timestamp that matches the
|
||||
UTC offset of the input timestamp.
|
||||
|
||||
```sql
|
||||
date_bin_wallclock(interval, expression[, origin_timestamp])
|
||||
```
|
||||
|
||||
##### Arguments:
|
||||
|
||||
- **interval**: Bin interval. Supports the following interval units:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
|
||||
> [!Note]
|
||||
> `date_bin_wallclock` does _not_ support month-, year-, or century-based intervals.
|
||||
|
||||
- **expression**: Time expression to operate on.
|
||||
Can be a constant, column, or function.
|
||||
The output timestamp uses the time zone from this time expression.
|
||||
- **origin_timestamp**: Starting point used to determine bin boundaries.
|
||||
This must be a "wall clock" timestamp (no time zone).
|
||||
_Default is the Unix epoch._
|
||||
|
||||
> [!Important]
|
||||
>
|
||||
> #### Avoid bins in time zone discontinuities
|
||||
>
|
||||
> [Time zone shifts](#time-zone-shifts) result in *discontinuities*–breaks
|
||||
> in the continuity of time intervals (losing an hour or gaining an hour)–that
|
||||
> can result in unexpected timestamps when using `date_bin_wallclock`.
|
||||
> Avoid using an `interval` and `origin_timestamp` combination that results in a
|
||||
> bin falling inside a time discontinuity.
|
||||
>
|
||||
> As a general rule, use either the default `origin_timestamp` or an origin
|
||||
> timestamp with an offset relative to the Unix epoch that is equal to your
|
||||
> specified `interval`.
|
||||
>
|
||||
> {{< expand-wrapper >}}
|
||||
{{% expand "View time zone discontinuity example" %}}
|
||||
|
||||
The following query illustrates how two timestamps, only one minute apart,
|
||||
result in timestamps two hours apart when binned across a daylight saving
|
||||
boundary:
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
tz('2020-10-25T02:29:00+01:00', 'Europe/Paris') AS original_time,
|
||||
date_bin_wallclock(
|
||||
INTERVAL '1 hour',
|
||||
tz('2020-10-25T02:29:00+01:00', 'Europe/Paris'),
|
||||
'1970-01-01T00:30:00'
|
||||
) AT TIME ZONE 'UTC' AS utc_bin_time
|
||||
UNION
|
||||
SELECT
|
||||
tz('2020-10-25T02:30:00+01:00', 'Europe/Paris') AS original_time,
|
||||
date_bin_wallclock(
|
||||
INTERVAL '1 hour',
|
||||
tz('2020-10-25T02:30:00+01:00', 'Europe/Paris'),
|
||||
'1970-01-01T00:30:00'
|
||||
) AT TIME ZONE 'UTC' AS utc_bin_time
|
||||
ORDER BY original_time;
|
||||
```
|
||||
|
||||
| original_time | utc_bin_time |
|
||||
| :------------------------ | :------------------- |
|
||||
| 2020-10-25T02:29:00+01:00 | 2020-10-24T23:30:00Z |
|
||||
| 2020-10-25T02:30:00+01:00 | 2020-10-25T01:30:00Z |
|
||||
|
||||
{{% /expand %}}
|
||||
{{< /expand-wrapper >}}
|
||||
|
||||
{{< expand-wrapper >}}
|
||||
{{% expand "View `date_bin_wallclock` query example" %}}
|
||||
|
||||
The following query uses the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/clustered/get-started/write/#construct-line-protocol)
|
||||
and returns the 12-hour average temperature for each room using times in the
|
||||
`America/Los_Angeles` time zone.
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
date_bin_wallclock(INTERVAL '12 hours', tz(time, 'America/Los_Angeles')) AS time,
|
||||
room,
|
||||
avg(temp) AS avg_temp
|
||||
FROM home
|
||||
WHERE
|
||||
time >= '2022-01-01T08:00:00Z'
|
||||
AND time <= '2022-01-01T20:00:00Z'
|
||||
GROUP BY 1, room
|
||||
```
|
||||
|
||||
| time | room | avg_temp |
|
||||
| :------------------------ | :---------- | -----------------: |
|
||||
| 2022-01-01T00:00:00-08:00 | Kitchen | 22.61666666666667 |
|
||||
| 2022-01-01T12:00:00-08:00 | Kitchen | 22.7 |
|
||||
| 2022-01-01T00:00:00-08:00 | Living Room | 22.166666666666668 |
|
||||
| 2022-01-01T12:00:00-08:00 | Living Room | 22.2 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
|
||||
{{% /expand %}}
|
||||
{{< /expand-wrapper >}}
|
||||
|
||||
## date_bin_wallclock_gapfill
|
||||
|
||||
Calculates time intervals using the timezone of a specified time value and
|
||||
returns the start of the interval nearest to the specified timestamp.
|
||||
If no rows exist in a time interval, a new row is inserted with a `time` value
|
||||
set to the interval start time, all columns in the `GROUP BY` clause populated,
|
||||
and null values in aggregate columns.
|
||||
|
||||
Use `date_bin_wallclock_gapfill` with [`interpolate`](/influxdb/clustered/reference/sql/functions/misc/#interpolate)
|
||||
or [`locf`](/influxdb/clustered/reference/sql/functions/misc/#locf) to
|
||||
[fill gaps in data](/influxdb/clustered/query-data/sql/fill-gaps/)
|
||||
at specified time intervals in a specified time zone.
|
||||
|
||||
### Time zone shifts
|
||||
|
||||
Many regions use time zone shifts (such as daylight saving time (DST)).
|
||||
If a wall clock time bin starts at a time that does not exist in the specified
|
||||
time zone, the timestamp is adjusted to the time that is the same offset from
|
||||
the start of the day in that time zone.
|
||||
|
||||
If a wall clock time represents an ambiguous time in the region then the
|
||||
behavior depends on the size of the specified interval. If the interval is
|
||||
larger than the difference between the two possible timestamps, then the earlier
|
||||
timestamp is used. Otherwise, the function uses the timestamp that matches the
|
||||
UTC offset of the input timestamp.
|
||||
|
||||
```sql
|
||||
date_bin_wallclock_gapfill(interval, expression[, origin_timestamp])
|
||||
```
|
||||
|
||||
{{% note %}}
|
||||
`date_bin_wallclock_gapfill` requires [time bounds](/influxdb/clustered/query-data/sql/basic-query/#query-data-within-time-boundaries)
|
||||
in the `WHERE` clause.
|
||||
{{% /note %}}
|
||||
|
||||
##### Arguments:
|
||||
|
||||
- **interval**: Bin interval. Supports the following interval units:
|
||||
|
||||
- nanoseconds
|
||||
- microseconds
|
||||
- milliseconds
|
||||
- seconds
|
||||
- minutes
|
||||
- hours
|
||||
- days
|
||||
- weeks
|
||||
|
||||
> [!Note]
|
||||
> `date_bin_wallclock_gapfill` does _not_ support month-, year-, or century-based intervals.
|
||||
|
||||
- **expression**: Time expression to operate on.
|
||||
Can be a constant, column, or function.
|
||||
The output timestamp uses the time zone from this time expression.
|
||||
- **origin_timestamp**: Starting point used to determine bin boundaries.
|
||||
This must be a "wall clock" timestamp (no time zone).
|
||||
_Default is the Unix epoch._
|
||||
|
||||
> [!Important]
|
||||
>
|
||||
> #### Avoid bins in time zone discontinuities
|
||||
>
|
||||
> [Time zone shifts](#time-zone-shifts) result in *discontinuities*–breaks
|
||||
> in the continuity of time intervals (losing an hour or gaining an hour)–that
|
||||
> can result in unexpected timestamps when using `date_bin_wallclock_gapfill`.
|
||||
> Avoid using an `interval` and `origin_timestamp` combination that results in a
|
||||
> bin falling inside a time discontinuity.
|
||||
>
|
||||
> As a general rule, use either the default `origin_timestamp` or an origin
|
||||
> timestamp with an offset relative to the Unix epoch that is equal to your
|
||||
> specified `interval`.
|
||||
>
|
||||
> [View time zone discontinuity example](#view-time-zone-discontinuity-example)
|
||||
|
||||
##### Related functions
|
||||
|
||||
[interpolate](/influxdb/clustered/reference/sql/functions/misc/#interpolate),
|
||||
[locf](/influxdb/clustered/reference/sql/functions/misc/#locf)
|
||||
|
||||
{{< expand-wrapper >}}
|
||||
{{% expand "Use `date_bin_wallclock_gapfill` to insert rows when no rows exists" %}}
|
||||
|
||||
_The following example uses the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/clustered/get-started/write/#construct-line-protocol)._
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
date_bin_wallclock_gapfill(INTERVAL '30 minutes', tz(time, 'America/Los_Angeles')) as time,
|
||||
room,
|
||||
avg(temp) as temp
|
||||
FROM home
|
||||
WHERE
|
||||
time >= '2022-01-01T08:00:00Z'
|
||||
AND time <= '2022-01-01T10:00:00Z'
|
||||
GROUP BY 1, room
|
||||
```
|
||||
|
||||
| time | room | temp |
|
||||
| :------------------------ | :---------- | ---: |
|
||||
| 2022-01-01T00:00:00-08:00 | Kitchen | 21 |
|
||||
| 2022-01-01T00:30:00-08:00 | Kitchen | |
|
||||
| 2022-01-01T01:00:00-08:00 | Kitchen | 23 |
|
||||
| 2022-01-01T01:30:00-08:00 | Kitchen | |
|
||||
| 2022-01-01T02:00:00-08:00 | Kitchen | 22.7 |
|
||||
| 2022-01-01T00:00:00-08:00 | Living Room | 21.1 |
|
||||
| 2022-01-01T00:30:00-08:00 | Living Room | |
|
||||
| 2022-01-01T01:00:00-08:00 | Living Room | 21.4 |
|
||||
| 2022-01-01T01:30:00-08:00 | Living Room | |
|
||||
| 2022-01-01T02:00:00-08:00 | Living Room | 21.8 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
{{% /expand %}}
|
||||
|
||||
{{% expand "Use `date_bin_wallclock_gapfill` to fill gaps in data" %}}
|
||||
|
||||
Use `interpolate` and `locf` to fill the null values in rows inserted by
|
||||
`date_bin_wallclock_gapfill`.
|
||||
|
||||
_The following examples use the sample data set provided in the
|
||||
[Get started with InfluxDB tutorial](/influxdb/clustered/get-started/write/#construct-line-protocol)._
|
||||
|
||||
{{< tabs-wrapper >}}
|
||||
{{% tabs "small" %}}
|
||||
[interpolate](#)
|
||||
[locf](#)
|
||||
{{% /tabs %}}
|
||||
{{% tab-content %}}
|
||||
|
||||
The example below uses [`interpolate`](/influxdb/clustered/reference/sql/functions/misc/#interpolate)
|
||||
to fill null values by interpolating values between non-null values.
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
date_bin_wallclock_gapfill(INTERVAL '30 minutes', tz(time, 'America/Los_Angeles')) as time,
|
||||
room,
|
||||
interpolate(avg(temp))
|
||||
FROM home
|
||||
WHERE
|
||||
time >= '2022-01-01T08:00:00Z'
|
||||
AND time <= '2022-01-01T10:00:00Z'
|
||||
GROUP BY 1, room
|
||||
```
|
||||
|
||||
| time | room | interpolate(avg(home.temp)) |
|
||||
| :------------------------ | :---------- | --------------------------: |
|
||||
| 2022-01-01T00:00:00-08:00 | Kitchen | 21 |
|
||||
| 2022-01-01T00:30:00-08:00 | Kitchen | 22 |
|
||||
| 2022-01-01T01:00:00-08:00 | Kitchen | 23 |
|
||||
| 2022-01-01T01:30:00-08:00 | Kitchen | 22.85 |
|
||||
| 2022-01-01T02:00:00-08:00 | Kitchen | 22.7 |
|
||||
| 2022-01-01T00:00:00-08:00 | Living Room | 21.1 |
|
||||
| 2022-01-01T00:30:00-08:00 | Living Room | 21.25 |
|
||||
| 2022-01-01T01:00:00-08:00 | Living Room | 21.4 |
|
||||
| 2022-01-01T01:30:00-08:00 | Living Room | 21.6 |
|
||||
| 2022-01-01T02:00:00-08:00 | Living Room | 21.8 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
|
||||
{{% /tab-content %}}
|
||||
{{% tab-content %}}
|
||||
|
||||
The example below uses [`locf`](/influxdb/clustered/reference/sql/functions/misc/#locf)
|
||||
to fill null values by carrying the last observed value forward.
|
||||
|
||||
{{% influxdb/custom-timestamps %}}
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
date_bin_wallclock_gapfill(INTERVAL '30 minutes', tz(time, 'America/Los_Angeles')) as time,
|
||||
room,
|
||||
locf(avg(temp))
|
||||
FROM home
|
||||
WHERE
|
||||
time >= '2022-01-01T08:00:00Z'
|
||||
AND time <= '2022-01-01T10:00:00Z'
|
||||
GROUP BY 1, room
|
||||
```
|
||||
|
||||
| time | room | locf(avg(home.temp)) |
|
||||
| :------------------------ | :---------- | -------------------: |
|
||||
| 2022-01-01T00:00:00-08:00 | Kitchen | 21 |
|
||||
| 2022-01-01T00:30:00-08:00 | Kitchen | 21 |
|
||||
| 2022-01-01T01:00:00-08:00 | Kitchen | 23 |
|
||||
| 2022-01-01T01:30:00-08:00 | Kitchen | 23 |
|
||||
| 2022-01-01T02:00:00-08:00 | Kitchen | 22.7 |
|
||||
| 2022-01-01T00:00:00-08:00 | Living Room | 21.1 |
|
||||
| 2022-01-01T00:30:00-08:00 | Living Room | 21.1 |
|
||||
| 2022-01-01T01:00:00-08:00 | Living Room | 21.4 |
|
||||
| 2022-01-01T01:30:00-08:00 | Living Room | 21.4 |
|
||||
| 2022-01-01T02:00:00-08:00 | Living Room | 21.8 |
|
||||
|
||||
{{% /influxdb/custom-timestamps %}}
|
||||
|
||||
{{% /tab-content %}}
|
||||
{{< /tabs-wrapper >}}
|
||||
|
||||
{{% /expand %}}
|
||||
{{< /expand-wrapper >}}
|
||||
|
||||
## date_trunc
|
||||
|
||||
|
@ -740,7 +1072,7 @@ SELECT
|
|||
|
||||
Converts a timestamp with a timezone to a timestamp without a timezone
|
||||
(no offset or timezone information). This function accounts for time shifts
|
||||
like Daylight Saving Time (DST) or British Summer Time (BST).
|
||||
like daylight saving time (DST).
|
||||
|
||||
{{% note %}}
|
||||
Use `to_local_time()` with [`date_bin()`](#date_bin) and
|
||||
|
@ -1120,19 +1452,24 @@ SELECT tz(time, 'Australia/Sydney') AS time_tz, time FROM home ORDER BY time LIM
|
|||
{{< /expand-wrapper >}}
|
||||
|
||||
##### Differences between tz and AT TIME ZONE
|
||||
`tz` and [`AT TIME ZONE`](/influxdb/cloud-serverless/reference/sql/operators/other/#at-time-zone)
|
||||
|
||||
`tz` and [`AT TIME ZONE`](/influxdb/clustered/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')
|
||||
|
@ -1140,18 +1477,22 @@ differ when the input timestamp **does not** have a timezone.
|
|||
-- 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
|
||||
|
|
36
yarn.lock
36
yarn.lock
|
@ -17,9 +17,9 @@
|
|||
integrity sha512-Ed61U6XJc3CVRfkERJWDz4dJwKe7iLmmJsbOGu9wSloNSFttHV0I8g6UAgb7qnK5ly5bGLPd4oXZlxCdANBOWQ==
|
||||
|
||||
"@evilmartians/lefthook@^1.7.1":
|
||||
version "1.8.4"
|
||||
resolved "https://registry.yarnpkg.com/@evilmartians/lefthook/-/lefthook-1.8.4.tgz#131baf2a3e432cb378c7f4fd2263a982478a6ccd"
|
||||
integrity sha512-n5aODynRZKSYmDajD8UCd5yy5ste2lJUTSGmv+D+4OP0UUWZqF4qJ/r7+2Ifo6K6WdsknVhVsPsEl4LugTbrug==
|
||||
version "1.8.5"
|
||||
resolved "https://registry.yarnpkg.com/@evilmartians/lefthook/-/lefthook-1.8.5.tgz#ce4805e7a67374d953946ea93a666939019123e9"
|
||||
integrity sha512-TuAL6W+bj2DqYxqm5JnFi3s7RnjpU/IUxxHFZWUHNytZ+HDQfkceogo+1DlSBFXFva2V21CSaDkeWJJHOmmECw==
|
||||
|
||||
"@isaacs/cliui@^8.0.2":
|
||||
version "8.0.2"
|
||||
|
@ -149,9 +149,9 @@ autoprefixer@>=10.2.5:
|
|||
postcss-value-parser "^4.2.0"
|
||||
|
||||
axios@^1.4.0, axios@^1.7.4:
|
||||
version "1.7.8"
|
||||
resolved "https://registry.yarnpkg.com/axios/-/axios-1.7.8.tgz#1997b1496b394c21953e68c14aaa51b7b5de3d6e"
|
||||
integrity sha512-Uu0wb7KNqK2t5K+YQyVCLM76prD5sRFjKHbJYCP1J7JFGEQ6nN7HWn9+04LAeiJ3ji54lgS/gZCH1oxyrf1SPw==
|
||||
version "1.7.9"
|
||||
resolved "https://registry.yarnpkg.com/axios/-/axios-1.7.9.tgz#d7d071380c132a24accda1b2cfc1535b79ec650a"
|
||||
integrity sha512-LhLcE7Hbiryz8oMDdDptSrWowmB4Bl6RCt6sIJKpRB4XtVf0iEgewX3au/pJqm+Py1kCASkb/FFKjxQaLtxJvw==
|
||||
dependencies:
|
||||
follow-redirects "^1.15.6"
|
||||
form-data "^4.0.0"
|
||||
|
@ -290,9 +290,9 @@ cacheable-request@^10.2.8:
|
|||
responselike "^3.0.0"
|
||||
|
||||
caniuse-lite@^1.0.30001646, caniuse-lite@^1.0.30001669:
|
||||
version "1.0.30001684"
|
||||
resolved "https://registry.yarnpkg.com/caniuse-lite/-/caniuse-lite-1.0.30001684.tgz#0eca437bab7d5f03452ff0ef9de8299be6b08e16"
|
||||
integrity sha512-G1LRwLIQjBQoyq0ZJGqGIJUXzJ8irpbjHLpVRXDvBEScFJ9b17sgK6vlx0GAJFE21okD7zXl08rRRUfq6HdoEQ==
|
||||
version "1.0.30001686"
|
||||
resolved "https://registry.yarnpkg.com/caniuse-lite/-/caniuse-lite-1.0.30001686.tgz#0e04b8d90de8753188e93c9989d56cb19d902670"
|
||||
integrity sha512-Y7deg0Aergpa24M3qLC5xjNklnKnhsmSyR/V89dLZ1n0ucJIFNs7PgR2Yfa/Zf6W79SbBicgtGxZr2juHkEUIA==
|
||||
|
||||
careful-downloader@^3.0.0:
|
||||
version "3.0.0"
|
||||
|
@ -497,9 +497,9 @@ eastasianwidth@^0.2.0:
|
|||
integrity sha512-I88TYZWc9XiYHRQ4/3c5rjjfgkjhLyW2luGIheGERbNQ6OY7yTybanSpDXZa8y7VUP9YmDcYa+eyq4ca7iLqWA==
|
||||
|
||||
electron-to-chromium@^1.5.41:
|
||||
version "1.5.65"
|
||||
resolved "https://registry.yarnpkg.com/electron-to-chromium/-/electron-to-chromium-1.5.65.tgz#e2b9d84d31e187a847e3ccdcfb415ddd4a3d1ea7"
|
||||
integrity sha512-PWVzBjghx7/wop6n22vS2MLU8tKGd4Q91aCEGhG/TYmW6PP5OcSXcdnxTe1NNt0T66N8D6jxh4kC8UsdzOGaIw==
|
||||
version "1.5.71"
|
||||
resolved "https://registry.yarnpkg.com/electron-to-chromium/-/electron-to-chromium-1.5.71.tgz#d8b5dba1e55b320f2f4e9b1ca80738f53fcfec2b"
|
||||
integrity sha512-dB68l59BI75W1BUGVTAEJy45CEVuEGy9qPVVQ8pnHyHMn36PLPPoE1mjLH+lo9rKulO3HC2OhbACI/8tCqJBcA==
|
||||
|
||||
emoji-regex@^8.0.0:
|
||||
version "8.0.0"
|
||||
|
@ -944,9 +944,9 @@ keyv@^4.5.3:
|
|||
json-buffer "3.0.1"
|
||||
|
||||
lilconfig@^3.1.1:
|
||||
version "3.1.2"
|
||||
resolved "https://registry.yarnpkg.com/lilconfig/-/lilconfig-3.1.2.tgz#e4a7c3cb549e3a606c8dcc32e5ae1005e62c05cb"
|
||||
integrity sha512-eop+wDAvpItUys0FWkHIKeC9ybYrTGbU41U5K7+bttZZeohvnY7M9dZ5kB21GNWiFT2q1OoPTvncPCgSOVO5ow==
|
||||
version "3.1.3"
|
||||
resolved "https://registry.yarnpkg.com/lilconfig/-/lilconfig-3.1.3.tgz#a1bcfd6257f9585bf5ae14ceeebb7b559025e4c4"
|
||||
integrity sha512-/vlFKAoH5Cgt3Ie+JLhRbwOsCQePABiU3tJ1egGvyQ+33R/vcwM2Zl2QR/LzjsBeItPt3oSVXapn+m4nQDvpzw==
|
||||
|
||||
lines-and-columns@^1.1.6:
|
||||
version "1.2.4"
|
||||
|
@ -1320,9 +1320,9 @@ prettier-plugin-sql@^0.18.0:
|
|||
tslib "^2.6.2"
|
||||
|
||||
prettier@^3.2.5:
|
||||
version "3.4.1"
|
||||
resolved "https://registry.yarnpkg.com/prettier/-/prettier-3.4.1.tgz#e211d451d6452db0a291672ca9154bc8c2579f7b"
|
||||
integrity sha512-G+YdqtITVZmOJje6QkXQWzl3fSfMxFwm1tjTyo9exhkmWSqC4Yhd1+lug++IlR2mvRVAxEDDWYkQdeSztajqgg==
|
||||
version "3.4.2"
|
||||
resolved "https://registry.yarnpkg.com/prettier/-/prettier-3.4.2.tgz#a5ce1fb522a588bf2b78ca44c6e6fe5aa5a2b13f"
|
||||
integrity sha512-e9MewbtFo+Fevyuxn/4rrcDAaq0IYxPGLvObpQjiZBMAzB9IGmzlnG9RZy3FFas+eBMu2vA0CszMeduow5dIuQ==
|
||||
|
||||
pretty-hrtime@^1.0.3:
|
||||
version "1.0.3"
|
||||
|
|
Loading…
Reference in New Issue