timeSeriesResampleToGridWithStaleness
Aggregate function that takes time series data as pairs of timestamps and values and re-samples this data to a regular time grid described by start timestamp, end timestamp and step. For each point on the grid the most recent (within the specified time window) sample is chosen.
Alias: timeSeriesLastToGrid.
Parameters:
start timestamp - specifies start of the grid
end timestamp - specifies end of the grid
grid step - specifies step of the grid in seconds
staleness window - specified the maximum "staleness" of the most recent sample in seconds
Arguments:
timestamp - timestamp of the sample
value - value of the time series corresponding to the timestamp
Return value:
time series values re-sampled to the specified grid as an Array(Nullable(Float64)). The returned array contains one value for each time grid point. The value is NULL if there is no sample for a particular grid point.
Example:
The following query re-samples time series data to the grid [90, 105, 120, 135, 150, 165, 180, 195, 210] by choosing the value no older than 30 sec for each point on the grid:
WITH
-- NOTE: the gap between 140 and 190 is to show how values are filled for ts = 150, 165, 180 according to staleness window parameter
[110, 120, 130, 140, 190, 200, 210, 220, 230]::Array(DateTime) AS timestamps,
[1, 1, 3, 4, 5, 5, 8, 12, 13]::Array(Float32) AS values, -- array of values corresponding to timestamps above
90 AS start_ts, -- start of timestamp grid
90 + 120 AS end_ts, -- end of timestamp grid
15 AS step_seconds, -- step of timestamp grid
30 AS window_seconds -- "staleness" window
SELECT timeSeriesResampleToGridWithStaleness(start_ts, end_ts, step_seconds, window_seconds)(timestamp, value)
FROM
(
-- This subquery converts arrays of timestamps and values into rows of `timestamp`, `value`
SELECT
arrayJoin(arrayZip(timestamps, values)) AS ts_and_val,
ts_and_val.1 AS timestamp,
ts_and_val.2 AS value
);
Response:
┌─timeSeriesResa⋯stamp, value)─┐
1. │ [NULL,NULL,1,3,4,4,NULL,5,8] │
└──────────────────────────────┘
Also it is possible to pass multiple samples of timestamps and values as Arrays of equal size. The same query with array arguments:
WITH
[110, 120, 130, 140, 190, 200, 210, 220, 230]::Array(DateTime) AS timestamps,
[1, 1, 3, 4, 5, 5, 8, 12, 13]::Array(Float32) AS values,
90 AS start_ts,
90 + 120 AS end_ts,
15 AS step_seconds,
30 AS window_seconds
SELECT timeSeriesResampleToGridWithStaleness(start_ts, end_ts, step_seconds, window_seconds)(timestamps, values);
Note
This function is experimental, enable it by setting allow_experimental_ts_to_grid_aggregate_function=true.
timeSeriesResampleToGridWithStaleness
Introduced in: v25.6
Aggregate function that takes time series data as pairs of timestamps and values and re-samples this data to a regular time grid described by start timestamp, end timestamp and step. For each point on the grid the most recent (within the specified time window) sample is chosen.
Alias: timeSeriesLastToGrid.
Note
This function is experimental, enable it by setting allow_experimental_ts_to_grid_aggregate_function=true.
Syntax
timeSeriesResampleToGridWithStaleness(start_timestamp, end_timestamp, grid_step, staleness_window)(timestamp, value)
Aliases: timeSeriesLastToGrid
Parameters
start_timestamp — Specifies start of the grid. UInt32 or DateTime
end_timestamp — Specifies end of the grid. UInt32 or DateTime
grid_step — Specifies step of the grid in seconds. UInt32
staleness_window — Specifies the maximum staleness of the most recent sample in seconds. UInt32
Arguments
Returned value
Returns time series values re-sampled to the specified grid. The returned array contains one value for each time grid point. The value is NULL if there is no sample for a particular grid point. Array(Nullable(Float64))
Examples
Basic usage with individual timestamp-value pairs
WITH
-- NOTE: the gap between 140 and 190 is to show how values are filled for ts = 150, 165, 180 according to staleness window parameter
[110, 120, 130, 140, 190, 200, 210, 220, 230]::Array(DateTime) AS timestamps,
[1, 1, 3, 4, 5, 5, 8, 12, 13]::Array(Float32) AS values, -- array of values corresponding to timestamps above
90 AS start_ts, -- start of timestamp grid
90 + 120 AS end_ts, -- end of timestamp grid
15 AS step_seconds, -- step of timestamp grid
30 AS window_seconds -- "staleness" window
SELECT timeSeriesResampleToGridWithStaleness(start_ts, end_ts, step_seconds, window_seconds)(timestamp, value)
FROM
(
-- This subquery converts arrays of timestamps and values into rows of `timestamp`, `value`
SELECT
arrayJoin(arrayZip(timestamps, values)) AS ts_and_val,
ts_and_val.1 AS timestamp,
ts_and_val.2 AS value
);
┌─timeSeriesResampleToGridWithStaleness(start_ts, end_ts, step_seconds, window_seconds)(timestamp, value)─┐
│ [NULL,NULL,1,3,4,4,NULL,5,8] │
└────────────────────────────────────────────────────────────────────────────────────────────────────┘
Using array arguments
WITH
[110, 120, 130, 140, 190, 200, 210, 220, 230]::Array(DateTime) AS timestamps,
[1, 1, 3, 4, 5, 5, 8, 12, 13]::Array(Float32) AS values,
90 AS start_ts,
90 + 120 AS end_ts,
15 AS step_seconds,
30 AS window_seconds
SELECT timeSeriesResampleToGridWithStaleness(start_ts, end_ts, step_seconds, window_seconds)(timestamps, values);
┌─timeSeriesResampleToGridWithStaleness(start_ts, end_ts, step_seconds, window_seconds)(timestamps, values)─┐
│ [NULL,NULL,1,3,4,4,NULL,5,8] │
└──────────────────────────────────────────────────────────────────────────────────────────────────────┘