date_bin FunctionThe date_bin function is a scalar function that aligns timestamps to the start of specified time intervals. It is commonly used with the GROUP BY clause for downsampling.
Sample Dataset: The example data page contains SQL statements for building table structures and inserting data. Download and execute these statements in the IoTDB CLI to import the data into IoTDB. You can use this data to test and execute the SQL statements in the examples and obtain the corresponding results.
Example 1: Hourly Average Temperature for Device 100
SELECT date_bin(1h, time) AS hour_time, avg(temperature) AS avg_temp FROM table1 WHERE (time >= 2024-11-27 00:00:00 AND time <= 2024-11-30 00:00:00) AND device_id = '100' GROUP BY 1;
Result
+-----------------------------+--------+ | hour_time|avg_temp| +-----------------------------+--------+ |2024-11-29T11:00:00.000+08:00| null| |2024-11-29T18:00:00.000+08:00| 90.0| |2024-11-28T08:00:00.000+08:00| 85.0| |2024-11-28T09:00:00.000+08:00| null| |2024-11-28T10:00:00.000+08:00| 85.0| |2024-11-28T11:00:00.000+08:00| 88.0| +-----------------------------+--------+
Example 2: Hourly Average Temperature for Each Device
SELECT date_bin(1h, time) AS hour_time, device_id, avg(temperature) AS avg_temp FROM table1 WHERE time >= 2024-11-27 00:00:00 AND time <= 2024-11-30 00:00:00 GROUP BY 1, device_id;
Result
+-----------------------------+---------+--------+ | hour_time|device_id|avg_temp| +-----------------------------+---------+--------+ |2024-11-29T11:00:00.000+08:00| 100| null| |2024-11-29T18:00:00.000+08:00| 100| 90.0| |2024-11-28T08:00:00.000+08:00| 100| 85.0| |2024-11-28T09:00:00.000+08:00| 100| null| |2024-11-28T10:00:00.000+08:00| 100| 85.0| |2024-11-28T11:00:00.000+08:00| 100| 88.0| |2024-11-29T10:00:00.000+08:00| 101| 85.0| |2024-11-27T16:00:00.000+08:00| 101| 85.0| +-----------------------------+---------+--------+
Example 3: Hourly Average Temperature for All Devices
SELECT date_bin(1h, time) AS hour_time, avg(temperature) AS avg_temp FROM table1 WHERE time >= 2024-11-27 00:00:00 AND time <= 2024-11-30 00:00:00 group by 1;
Result
+-----------------------------+--------+ | hour_time|avg_temp| +-----------------------------+--------+ |2024-11-29T10:00:00.000+08:00| 85.0| |2024-11-27T16:00:00.000+08:00| 85.0| |2024-11-29T11:00:00.000+08:00| null| |2024-11-29T18:00:00.000+08:00| 90.0| |2024-11-28T08:00:00.000+08:00| 85.0| |2024-11-28T09:00:00.000+08:00| null| |2024-11-28T10:00:00.000+08:00| 85.0| |2024-11-28T11:00:00.000+08:00| 88.0| +-----------------------------+--------+
date_bin_gapfill FunctionThe date_bin_gapfill function is an extension of date_bin that fills in missing time intervals, returning a complete time series.
GROUP BY clause. If used elsewhere, it behaves like date_bin without gap-filling.GROUP BY clause can contain only one instance of date_bin_gapfill. Multiple calls will result in an error.GAPFILL operation occurs after the HAVING clause and before the FILL clause.WHERE clause must include time filters in one of the following forms:time >= XXX AND time <= XXXtime > XXX AND time < XXXtime BETWEEN XXX AND XXXAND operator.startTime and endTime cannot be inferred from the WHERE clause, an error is raised.Usage Examples
Example 1: Fill Missing Intervals
SELECT date_bin_gapfill(1h, time) AS hour_time, avg(temperature) AS avg_temp FROM table1 WHERE (time >= 2024-11-28 07:00:00 AND time <= 2024-11-28 16:00:00) AND device_id = '100' GROUP BY 1;
Result
+-----------------------------+--------+ | hour_time|avg_temp| +-----------------------------+--------+ |2024-11-28T07:00:00.000+08:00| null| |2024-11-28T08:00:00.000+08:00| 85.0| |2024-11-28T09:00:00.000+08:00| null| |2024-11-28T10:00:00.000+08:00| 85.0| |2024-11-28T11:00:00.000+08:00| 88.0| |2024-11-28T12:00:00.000+08:00| null| |2024-11-28T13:00:00.000+08:00| null| |2024-11-28T14:00:00.000+08:00| null| |2024-11-28T15:00:00.000+08:00| null| |2024-11-28T16:00:00.000+08:00| null| +-----------------------------+--------+
Example 2: Fill Missing Intervals with Device Grouping
SELECT date_bin_gapfill(1h, time) AS hour_time, device_id, avg(temperature) AS avg_temp FROM table1 WHERE time >= 2024-11-28 07:00:00 AND time <= 2024-11-28 16:00:00 GROUP BY 1, device_id;
Result
+-----------------------------+---------+--------+ | hour_time|device_id|avg_temp| +-----------------------------+---------+--------+ |2024-11-28T07:00:00.000+08:00| 100| null| |2024-11-28T08:00:00.000+08:00| 100| 85.0| |2024-11-28T09:00:00.000+08:00| 100| null| |2024-11-28T10:00:00.000+08:00| 100| 85.0| |2024-11-28T11:00:00.000+08:00| 100| 88.0| |2024-11-28T12:00:00.000+08:00| 100| null| |2024-11-28T13:00:00.000+08:00| 100| null| |2024-11-28T14:00:00.000+08:00| 100| null| |2024-11-28T15:00:00.000+08:00| 100| null| |2024-11-28T16:00:00.000+08:00| 100| null| +-----------------------------+---------+--------+
Example 3: Empty Result Set for No Data in Range
SELECT date_bin_gapfill(1h, time) AS hour_time, device_id, avg(temperature) AS avg_temp FROM table1 WHERE time >= 2024-11-27 09:00:00 AND time <= 2024-11-27 14:00:00 GROUP BY 1, device_id;
Result
+---------+---------+--------+ |hour_time|device_id|avg_temp| +---------+---------+--------+ +---------+---------+--------+
DIFF FunctionDIFF function calculates the difference between the current row and the previous row. For the first row, it returns NULL since there is no previous row.DIFF(numberic[, boolean]) -> Double
INT32, INT64, FLOAT, DOUBLE).true or false).true.true: Ignores NULL values and uses the first non-NULL value for calculation. If no non-NULL value exists, returns NULL.false: Does not ignore NULL values. If the previous row is NULL, the result is NULL.'ignoreNull'='true' or 'ignoreNull'='false'.true or false. Using 'ignoreNull'='true' or 'ignoreNull'='false' in table models results in a string comparison and always evaluates to false.SELECT time, DIFF(temperature) AS diff_temp FROM table1 WHERE device_id = '100';
Result
+-----------------------------+---------+ | time|diff_temp| +-----------------------------+---------+ |2024-11-29T11:00:00.000+08:00| null| |2024-11-29T18:30:00.000+08:00| null| |2024-11-28T08:00:00.000+08:00| -5.0| |2024-11-28T09:00:00.000+08:00| null| |2024-11-28T10:00:00.000+08:00| 0.0| |2024-11-28T11:00:00.000+08:00| 3.0| |2024-11-26T13:37:00.000+08:00| 2.0| |2024-11-26T13:38:00.000+08:00| 0.0| +-----------------------------+---------+
SELECT time, DIFF(temperature, false) AS diff_temp FROM table1 WHERE device_id = '100';
Result
+-----------------------------+---------+ | time|diff_temp| +-----------------------------+---------+ |2024-11-29T11:00:00.000+08:00| null| |2024-11-29T18:30:00.000+08:00| null| |2024-11-28T08:00:00.000+08:00| -5.0| |2024-11-28T09:00:00.000+08:00| null| |2024-11-28T10:00:00.000+08:00| null| |2024-11-28T11:00:00.000+08:00| 3.0| |2024-11-26T13:37:00.000+08:00| 2.0| |2024-11-26T13:38:00.000+08:00| 0.0| +-----------------------------+---------+
SELECT time, temperature, DIFF(temperature) AS diff_temp_1, DIFF(temperature, false) AS diff_temp_2 FROM table1 WHERE device_id = '100';
Result
+-----------------------------+-----------+-----------+-----------+ | time|temperature|diff_temp_1|diff_temp_2| +-----------------------------+-----------+-----------+-----------+ |2024-11-29T11:00:00.000+08:00| null| null| null| |2024-11-29T18:30:00.000+08:00| 90.0| null| null| |2024-11-28T08:00:00.000+08:00| 85.0| -5.0| -5.0| |2024-11-28T09:00:00.000+08:00| null| null| null| |2024-11-28T10:00:00.000+08:00| 85.0| 0.0| null| |2024-11-28T11:00:00.000+08:00| 88.0| 3.0| 3.0| |2024-11-26T13:37:00.000+08:00| 90.0| 2.0| 2.0| |2024-11-26T13:38:00.000+08:00| 90.0| 0.0| 0.0| +-----------------------------+-----------+-----------+-----------+
The sample data is as follows:
IoTDB> SELECT * FROM bid; +-----------------------------+--------+-----+ | time|stock_id|price| +-----------------------------+--------+-----+ |2021-01-01T09:05:00.000+08:00| AAPL|100.0| |2021-01-01T09:06:00.000+08:00| TESL|200.0| |2021-01-01T09:07:00.000+08:00| AAPL|103.0| |2021-01-01T09:07:00.000+08:00| TESL|202.0| |2021-01-01T09:09:00.000+08:00| AAPL|102.0| |2021-01-01T09:15:00.000+08:00| TESL|195.0| +-----------------------------+--------+-----+ -- Create table statement CREATE TABLE bid(time TIMESTAMP TIME, stock_id STRING TAG, price FLOAT FIELD); -- Insert data INSERT INTO bid(time, stock_id, price) VALUES('2021-01-01T09:05:00','AAPL',100.0),('2021-01-01T09:06:00','TESL',200.0),('2021-01-01T09:07:00','AAPL',103.0),('2021-01-01T09:07:00','TESL',202.0),('2021-01-01T09:09:00','AAPL',102.0),('2021-01-01T09:15:00','TESL',195.0);
The HOP function segments data into overlapping time windows for analysis, assigning each row to all windows that overlap with its timestamp. If windows overlap (when SLIDE < SIZE), data will be duplicated across multiple windows.
HOP(data, timecol, size, slide[, origin])
| Parameter | Type | Attributes | Description |
|---|---|---|---|
| DATA | Table | ROW SEMANTIC, PASS THROUGH | Input table |
| TIMECOL | Scalar | String (default: ‘time’) | Time column |
| SIZE | Scalar | Long integer | Window size |
| SLIDE | Scalar | Long integer | Sliding step |
| ORIGIN | Scalar | Timestamp (default: Unix epoch) | First window start time |
The HOP function returns:
window_start: Window start time (inclusive)window_end: Window end time (exclusive)IoTDB> SELECT * FROM HOP(DATA => bid,TIMECOL => 'time',SLIDE => 5m,SIZE => 10m); +-----------------------------+-----------------------------+-----------------------------+--------+-----+ | window_start| window_end| time|stock_id|price| +-----------------------------+-----------------------------+-----------------------------+--------+-----+ |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:05:00.000+08:00| AAPL|100.0| |2021-01-01T09:05:00.000+08:00|2021-01-01T09:15:00.000+08:00|2021-01-01T09:05:00.000+08:00| AAPL|100.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:06:00.000+08:00| TESL|200.0| |2021-01-01T09:05:00.000+08:00|2021-01-01T09:15:00.000+08:00|2021-01-01T09:06:00.000+08:00| TESL|200.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:07:00.000+08:00| AAPL|103.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:07:00.000+08:00| TESL|202.0| |2021-01-01T09:05:00.000+08:00|2021-01-01T09:15:00.000+08:00|2021-01-01T09:07:00.000+08:00| AAPL|103.0| |2021-01-01T09:05:00.000+08:00|2021-01-01T09:15:00.000+08:00|2021-01-01T09:07:00.000+08:00| TESL|202.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:09:00.000+08:00| AAPL|102.0| |2021-01-01T09:05:00.000+08:00|2021-01-01T09:15:00.000+08:00|2021-01-01T09:09:00.000+08:00| AAPL|102.0| |2021-01-01T09:10:00.000+08:00|2021-01-01T09:20:00.000+08:00|2021-01-01T09:15:00.000+08:00| TESL|195.0| |2021-01-01T09:15:00.000+08:00|2021-01-01T09:25:00.000+08:00|2021-01-01T09:15:00.000+08:00| TESL|195.0| +-----------------------------+-----------------------------+-----------------------------+--------+-----+ -- Equivalent to tree model's GROUP BY TIME when combined with GROUP BY IoTDB> SELECT window_start, window_end, stock_id, avg(price) as avg FROM HOP(DATA => bid,TIMECOL => 'time',SLIDE => 5m,SIZE => 10m) GROUP BY window_start, window_end, stock_id; +-----------------------------+-----------------------------+--------+------------------+ | window_start| window_end|stock_id| avg| +-----------------------------+-----------------------------+--------+------------------+ |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00| TESL| 201.0| |2021-01-01T09:05:00.000+08:00|2021-01-01T09:15:00.000+08:00| TESL| 201.0| |2021-01-01T09:10:00.000+08:00|2021-01-01T09:20:00.000+08:00| TESL| 195.0| |2021-01-01T09:15:00.000+08:00|2021-01-01T09:25:00.000+08:00| TESL| 195.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00| AAPL|101.66666666666667| |2021-01-01T09:05:00.000+08:00|2021-01-01T09:15:00.000+08:00| AAPL|101.66666666666667| +-----------------------------+-----------------------------+--------+------------------+
The SESSION function groups data into sessions based on time intervals. It checks the time gap between consecutive rows—rows with gaps smaller than the threshold (GAP) are grouped into the current window, while larger gaps trigger a new window.
SESSION(data [PARTITION BY(pkeys, ...)] [ORDER BY(okeys, ...)], timecol, gap)
| Parameter | Type | Attributes | Description |
|---|---|---|---|
| DATA | Table | SET SEMANTIC, PASS THROUGH | Input table with partition/sort keys |
| TIMECOL | Scalar | String (default: ‘time’) | Time column name |
| GAP | Scalar | Long integer | Session gap threshold |
The SESSION function returns:
window_start: Time of the first row in the sessionwindow_end: Time of the last row in the sessionIoTDB> SELECT * FROM SESSION(DATA => bid PARTITION BY stock_id ORDER BY time,TIMECOL => 'time',GAP => 2m); +-----------------------------+-----------------------------+-----------------------------+--------+-----+ | window_start| window_end| time|stock_id|price| +-----------------------------+-----------------------------+-----------------------------+--------+-----+ |2021-01-01T09:06:00.000+08:00|2021-01-01T09:07:00.000+08:00|2021-01-01T09:06:00.000+08:00| TESL|200.0| |2021-01-01T09:06:00.000+08:00|2021-01-01T09:07:00.000+08:00|2021-01-01T09:07:00.000+08:00| TESL|202.0| |2021-01-01T09:15:00.000+08:00|2021-01-01T09:15:00.000+08:00|2021-01-01T09:15:00.000+08:00| TESL|195.0| |2021-01-01T09:05:00.000+08:00|2021-01-01T09:09:00.000+08:00|2021-01-01T09:05:00.000+08:00| AAPL|100.0| |2021-01-01T09:05:00.000+08:00|2021-01-01T09:09:00.000+08:00|2021-01-01T09:07:00.000+08:00| AAPL|103.0| |2021-01-01T09:05:00.000+08:00|2021-01-01T09:09:00.000+08:00|2021-01-01T09:09:00.000+08:00| AAPL|102.0| +-----------------------------+-----------------------------+-----------------------------+--------+-----+ -- Equivalent to tree model's GROUP BY SESSION when combined with GROUP BY IoTDB> SELECT window_start, window_end, stock_id, avg(price) as avg FROM SESSION(DATA => bid PARTITION BY stock_id ORDER BY time,TIMECOL => 'time',GAP => 2m) GROUP BY window_start, window_end, stock_id; +-----------------------------+-----------------------------+--------+------------------+ | window_start| window_end|stock_id| avg| +-----------------------------+-----------------------------+--------+------------------+ |2021-01-01T09:06:00.000+08:00|2021-01-01T09:07:00.000+08:00| TESL| 201.0| |2021-01-01T09:15:00.000+08:00|2021-01-01T09:15:00.000+08:00| TESL| 195.0| |2021-01-01T09:05:00.000+08:00|2021-01-01T09:09:00.000+08:00| AAPL|101.66666666666667| +-----------------------------+-----------------------------+--------+------------------+
The VARIATION function groups data based on value differences. The first row becomes the baseline for the first window. Subsequent rows are compared to the baseline—if the difference is within the threshold (DELTA), they join the current window; otherwise, a new window starts with that row as the new baseline.
VARIATION(data [PARTITION BY(pkeys, ...)] [ORDER BY(okeys, ...)], col, delta)
| Parameter | Type | Attributes | Description |
|---|---|---|---|
| DATA | Table | SET SEMANTIC, PASS THROUGH | Input table with partition/sort keys |
| COL | Scalar | String | Column for difference calculation |
| DELTA | Scalar | Float | Difference threshold |
The VARIATION function returns:
window_index: Window identifierIoTDB> SELECT * FROM VARIATION(DATA => bid PARTITION BY stock_id ORDER BY time,COL => 'price',DELTA => 2.0); +------------+-----------------------------+--------+-----+ |window_index| time|stock_id|price| +------------+-----------------------------+--------+-----+ | 0|2021-01-01T09:06:00.000+08:00| TESL|200.0| | 0|2021-01-01T09:07:00.000+08:00| TESL|202.0| | 1|2021-01-01T09:15:00.000+08:00| TESL|195.0| | 0|2021-01-01T09:05:00.000+08:00| AAPL|100.0| | 1|2021-01-01T09:07:00.000+08:00| AAPL|103.0| | 1|2021-01-01T09:09:00.000+08:00| AAPL|102.0| +------------+-----------------------------+--------+-----+ -- Equivalent to tree model's GROUP BY VARIATION when combined with GROUP BY IoTDB> SELECT first(time) as window_start, last(time) as window_end, stock_id, avg(price) as avg FROM VARIATION(DATA => bid PARTITION BY stock_id ORDER BY time,COL => 'price', DELTA => 2.0) GROUP BY window_index, stock_id; +-----------------------------+-----------------------------+--------+-----+ | window_start| window_end|stock_id| avg| +-----------------------------+-----------------------------+--------+-----+ |2021-01-01T09:06:00.000+08:00|2021-01-01T09:07:00.000+08:00| TESL|201.0| |2021-01-01T09:15:00.000+08:00|2021-01-01T09:15:00.000+08:00| TESL|195.0| |2021-01-01T09:05:00.000+08:00|2021-01-01T09:05:00.000+08:00| AAPL|100.0| |2021-01-01T09:07:00.000+08:00|2021-01-01T09:09:00.000+08:00| AAPL|102.5| +-----------------------------+-----------------------------+--------+-----+
The CAPACITY function groups data into fixed-size windows, where each window contains up to SIZE rows.
CAPACITY(data [PARTITION BY(pkeys, ...)] [ORDER BY(okeys, ...)], size)
| Parameter | Type | Attributes | Description |
|---|---|---|---|
| DATA | Table | SET SEMANTIC, PASS THROUGH | Input table with partition/sort keys |
| SIZE | Scalar | Long integer | Window size (row count) |
The CAPACITY function returns:
window_index: Window identifierIoTDB> SELECT * FROM CAPACITY(DATA => bid PARTITION BY stock_id ORDER BY time, SIZE => 2); +------------+-----------------------------+--------+-----+ |window_index| time|stock_id|price| +------------+-----------------------------+--------+-----+ | 0|2021-01-01T09:06:00.000+08:00| TESL|200.0| | 0|2021-01-01T09:07:00.000+08:00| TESL|202.0| | 1|2021-01-01T09:15:00.000+08:00| TESL|195.0| | 0|2021-01-01T09:05:00.000+08:00| AAPL|100.0| | 0|2021-01-01T09:07:00.000+08:00| AAPL|103.0| | 1|2021-01-01T09:09:00.000+08:00| AAPL|102.0| +------------+-----------------------------+--------+-----+ -- Equivalent to tree model's GROUP BY COUNT when combined with GROUP BY IoTDB> SELECT first(time) as start_time, last(time) as end_time, stock_id, avg(price) as avg FROM CAPACITY(DATA => bid PARTITION BY stock_id ORDER BY time, SIZE => 2) GROUP BY window_index, stock_id; +-----------------------------+-----------------------------+--------+-----+ | start_time| end_time|stock_id| avg| +-----------------------------+-----------------------------+--------+-----+ |2021-01-01T09:06:00.000+08:00|2021-01-01T09:07:00.000+08:00| TESL|201.0| |2021-01-01T09:15:00.000+08:00|2021-01-01T09:15:00.000+08:00| TESL|195.0| |2021-01-01T09:05:00.000+08:00|2021-01-01T09:07:00.000+08:00| AAPL|101.5| |2021-01-01T09:09:00.000+08:00|2021-01-01T09:09:00.000+08:00| AAPL|102.0| +-----------------------------+-----------------------------+--------+-----+
The TUMBLE function assigns each row to a non-overlapping, fixed-size time window based on a timestamp attribute.
TUMBLE(data, timecol, size[, origin])
| Parameter | Type | Attributes | Description |
|---|---|---|---|
| DATA | Table | ROW SEMANTIC, PASS THROUGH | Input table |
| TIMECOL | Scalar | String (default: ‘time’) | Time column |
| SIZE | Scalar | Long integer (positive) | Window size |
| ORIGIN | Scalar | Timestamp (default: Unix epoch) | First window start time |
The TUMBLE function returns:
window_start: Window start time (inclusive)window_end: Window end time (exclusive)IoTDB> SELECT * FROM TUMBLE( DATA => bid, TIMECOL => 'time', SIZE => 10m); +-----------------------------+-----------------------------+-----------------------------+--------+-----+ | window_start| window_end| time|stock_id|price| +-----------------------------+-----------------------------+-----------------------------+--------+-----+ |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:06:00.000+08:00| TESL|200.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:07:00.000+08:00| TESL|202.0| |2021-01-01T09:10:00.000+08:00|2021-01-01T09:20:00.000+08:00|2021-01-01T09:15:00.000+08:00| TESL|195.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:05:00.000+08:00| AAPL|100.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:07:00.000+08:00| AAPL|103.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:09:00.000+08:00| AAPL|102.0| +-----------------------------+-----------------------------+-----------------------------+--------+-----+ -- Equivalent to tree model's GROUP BY TIME when combined with GROUP BY IoTDB> SELECT window_start, window_end, stock_id, avg(price) as avg FROM TUMBLE(DATA => bid, TIMECOL => 'time', SIZE => 10m) GROUP BY window_start, window_end, stock_id; +-----------------------------+-----------------------------+--------+------------------+ | window_start| window_end|stock_id| avg| +-----------------------------+-----------------------------+--------+------------------+ |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00| TESL| 201.0| |2021-01-01T09:10:00.000+08:00|2021-01-01T09:20:00.000+08:00| TESL| 195.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00| AAPL|101.66666666666667| +-----------------------------+-----------------------------+--------+------------------+
The CUMULATE function creates expanding windows from an initial window, maintaining the same start time while incrementally extending the end time by STEP until reaching SIZE. Each window contains all elements within its range. For example, with a 1-hour STEP and 24-hour SIZE, daily windows would be: [00:00, 01:00), [00:00, 02:00), ..., [00:00, 24:00).
CUMULATE(data, timecol, size, step[, origin])
| Parameter | Type | Attributes | Description |
|---|---|---|---|
| DATA | Table | ROW SEMANTIC, PASS THROUGH | Input table |
| TIMECOL | Scalar | String (default: ‘time’) | Time column |
| SIZE | Scalar | Long integer (positive) | Window size (must be an integer multiple of STEP) |
| STEP | Scalar | Long integer (positive) | Expansion step |
| ORIGIN | Scalar | Timestamp (default: Unix epoch) | First window start time |
Note: An error
Cumulative table function requires size must be an integral multiple of stepoccurs if SIZE is not divisible by STEP.
The CUMULATE function returns:
window_start: Window start time (inclusive)window_end: Window end time (exclusive)IoTDB> SELECT * FROM CUMULATE(DATA => bid,TIMECOL => 'time',STEP => 2m,SIZE => 10m); +-----------------------------+-----------------------------+-----------------------------+--------+-----+ | window_start| window_end| time|stock_id|price| +-----------------------------+-----------------------------+-----------------------------+--------+-----+ |2021-01-01T09:00:00.000+08:00|2021-01-01T09:08:00.000+08:00|2021-01-01T09:06:00.000+08:00| TESL|200.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:06:00.000+08:00| TESL|200.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:08:00.000+08:00|2021-01-01T09:07:00.000+08:00| TESL|202.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:07:00.000+08:00| TESL|202.0| |2021-01-01T09:10:00.000+08:00|2021-01-01T09:16:00.000+08:00|2021-01-01T09:15:00.000+08:00| TESL|195.0| |2021-01-01T09:10:00.000+08:00|2021-01-01T09:18:00.000+08:00|2021-01-01T09:15:00.000+08:00| TESL|195.0| |2021-01-01T09:10:00.000+08:00|2021-01-01T09:20:00.000+08:00|2021-01-01T09:15:00.000+08:00| TESL|195.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:06:00.000+08:00|2021-01-01T09:05:00.000+08:00| AAPL|100.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:08:00.000+08:00|2021-01-01T09:05:00.000+08:00| AAPL|100.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:05:00.000+08:00| AAPL|100.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:08:00.000+08:00|2021-01-01T09:07:00.000+08:00| AAPL|103.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:07:00.000+08:00| AAPL|103.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00|2021-01-01T09:09:00.000+08:00| AAPL|102.0| +-----------------------------+-----------------------------+-----------------------------+--------+-----+ -- Equivalent to tree model's GROUP BY TIME when combined with GROUP BY IoTDB> SELECT window_start, window_end, stock_id, avg(price) as avg FROM CUMULATE(DATA => bid,TIMECOL => 'time',STEP => 2m, SIZE => 10m) GROUP BY window_start, window_end, stock_id; +-----------------------------+-----------------------------+--------+------------------+ | window_start| window_end|stock_id| avg| +-----------------------------+-----------------------------+--------+------------------+ |2021-01-01T09:00:00.000+08:00|2021-01-01T09:08:00.000+08:00| TESL| 201.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00| TESL| 201.0| |2021-01-01T09:10:00.000+08:00|2021-01-01T09:16:00.000+08:00| TESL| 195.0| |2021-01-01T09:10:00.000+08:00|2021-01-01T09:18:00.000+08:00| TESL| 195.0| |2021-01-01T09:10:00.000+08:00|2021-01-01T09:20:00.000+08:00| TESL| 195.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:06:00.000+08:00| AAPL| 100.0| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:08:00.000+08:00| AAPL| 101.5| |2021-01-01T09:00:00.000+08:00|2021-01-01T09:10:00.000+08:00| AAPL|101.66666666666667| +-----------------------------+-----------------------------+--------+------------------+