Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -26,6 +26,24 @@ CREATE TABLE table2 (
arrival_time TIMESTAMP FIELD
) WITH (TTL=31536000000);

CREATE TABLE table3 (
time TIMESTAMP TIME,
device_id STRING TAG,
temperature FLOAT FIELD
)COMMENT 'table3' WITH (TTL=31536000000);

CREATE TABLE table4 (
time TIMESTAMP TIME,
device_id STRING TAG,
humidity FLOAT FIELD
) COMMENT 'table4' WITH (TTL=31536000000);

CREATE TABLE table5 (
time TIMESTAMP TIME,
device_id STRING TAG,
humidity FLOAT FIELD
) COMMENT 'table5' WITH (TTL=31536000000);


INSERT INTO table1(region, plant_id, device_id, model_id, maintenance, time, temperature, humidity, status, arrival_time) VALUES
('北京', '1001', '100', 'A', '180', '2024-11-26 13:37:00', 90.0, 35.1, true, '2024-11-26 13:37:34'),
Expand All @@ -47,13 +65,35 @@ INSERT INTO table1(region, plant_id, device_id, model_id, maintenance, time, tem
('上海', '3002', '101', 'F', '360', '2024-11-30 09:30:00', 90.0, 35.2, true, NULL),
('上海', '3002', '101', 'F', '360', '2024-11-30 14:30:00', 90.0, 34.8, true, '2024-11-30 14:30:17');



INSERT INTO table2(region, plant_id, device_id, model_id, maintenance, time, temperature, humidity, status, arrival_time) VALUES
('北京', '1001', '100', 'A', '180', '2024-11-26 13:37:00', 90.0, 35.1, true, '2024-11-26 13:37:34'),
('北京', '1001', '101', 'B', '180', '2024-11-27 00:00:00', 85.0, 35.1, true, '2024-11-27 16:37:01'),
('上海', '3001', '100', 'C', '90', '2024-11-28 08:00:00', 85.0, 35.2, false, '2024-11-28 08:00:09'),
('上海', '3001', '101', 'D', '360', '2024-11-29 00:00:00', 85.0, 35.1, NULL, '2024-11-29 10:00:13'),
('上海', '3002', '100', 'E', '180', '2024-11-29 11:00:00', NULL, 45.1, true, NULL),
('上海', '3002', '101', 'F', '360', '2024-11-30 00:00:00', 90.0, 35.2, true, NULL);

INSERT INTO table3(device_id, time, temperature) VALUES
('d1', '2025-05-13 00:00:00.001', 90.0),
('d1', '2025-05-13 00:00:01.002', 85.0),
('d1', '2025-05-13 00:00:02.101', 85.0),
('d1', '2025-05-13 00:00:03.201', null),
('d1', '2025-05-13 00:00:04.105', 90.0),
('d1', '2025-05-13 00:00:05.023', 85.0),
('d1', '2025-05-13 00:00:06.129', 90.0);

INSERT INTO table4(device_id, time, humidity) VALUES
('d1', '2025-05-13 00:00:00.003', 35.1),
('d1', '2025-05-13 00:00:01.012', 37.2),
('d1', '2025-05-13 00:00:02.031', null),
('d1', '2025-05-13 00:00:03.134', 35.2),
('d1', '2025-05-13 00:00:04.201', 38.2),
('d1', '2025-05-13 00:00:05.091', 35.4),
('d1', '2025-05-13 00:00:06.231', 35.1);

INSERT INTO table5(device_id, time, humidity) VALUES
('d1', '2025-05-13 00:00:00.005', 35.1),
('d1', '2025-05-13 00:00:02.106', 37.2),
('d1', '2025-05-13 00:00:04.187', null),
('d1', '2025-05-13 00:00:06.156', 35.1);

313 changes: 299 additions & 14 deletions src/UserGuide/Master/Table/Basic-Concept/Query-Data.md
Original file line number Diff line number Diff line change
Expand Up @@ -192,28 +192,313 @@ It costs 0.090s
**Example**: Group data by day and calculate the average temperature using `date_bin_gapfill` function.

```SQL
IoTDB> SELECT date_bin(1d ,time) as day_time, AVG(temperature) as avg_temp
IoTDB> SELECT device_id,date_bin(1d ,time) as day_time, AVG(temperature) as avg_temp
FROM table1
WHERE time >= 2024-11-26 00:00:00 AND time <= 2024-11-30 00:00:00
GROUP BY date_bin(1d ,time);
GROUP BY device_id,date_bin(1d ,time);
```

**Result**:

```SQL
+-----------------------------+--------+
| day_time|avg_temp|
+-----------------------------+--------+
|2024-11-29T08:00:00.000+08:00| 87.5|
|2024-11-28T08:00:00.000+08:00| 86.0|
|2024-11-26T08:00:00.000+08:00| 90.0|
|2024-11-27T08:00:00.000+08:00| 85.0|
+-----------------------------+--------+
Total line number = 4
It costs 0.110s
+---------+-----------------------------+--------+
|device_id| day_time|avg_temp|
+---------+-----------------------------+--------+
| 100|2024-11-29T08:00:00.000+08:00| 90.0|
| 100|2024-11-28T08:00:00.000+08:00| 86.0|
| 100|2024-11-26T08:00:00.000+08:00| 90.0|
| 101|2024-11-29T08:00:00.000+08:00| 85.0|
| 101|2024-11-27T08:00:00.000+08:00| 85.0|
+---------+-----------------------------+--------+
Total line number = 5
It costs 0.066s
```
### 3.6 Multi sequence downsampling query with misaligned timestamps

#### 3.6.1 Sampling Frequency is the Same, but Time is Different

**Table 1: Sampling Frequency: 1s**

| Time | device_id | temperature |
| ------------ | --------- | ----------- |
| 00:00:00.001 | d1 | 90.0 |
| 00:00:01.002 | d1 | 85.0 |
| 00:00:02.101 | d1 | 85.0 |
| 00:00:03.201 | d1 | null |
| 00:00:04.105 | d1 | 90.0 |
| 00:00:05.023 | d1 | 85.0 |
| 00:00:06.129 | d1 | 90.0 |

**Table 2: Sampling Frequency: 1s**

| Time | device_id | humidity |
| ------------ | --------- | -------- |
| 00:00:00.003 | d1 | 35.1 |
| 00:00:01.012 | d1 | 37.2 |
| 00:00:02.031 | d1 | null |
| 00:00:03.134 | d1 | 35.2 |
| 00:00:04.201 | d1 | 38.2 |
| 00:00:05.091 | d1 | 35.4 |
| 00:00:06.231 | d1 | 35.1 |

**Example: Querying the downsampled data of table1:**

```SQL
IoTDB> SELECT date_bin_gapfill(1s, TIME) AS a_time,
first(temperature) AS a_value
FROM table1
WHERE device_id = 'd1'
AND TIME >= 2025-05-13 00:00:00.000
AND TIME <= 2025-05-13 00:00:07.000
GROUP BY 1 FILL METHOD PREVIOUS
```

**Result:**

```SQL
+-----------------------------+-------+
| a_time|a_value|
+-----------------------------+-------+
|2025-05-13T00:00:00.000+08:00| 90.0|
|2025-05-13T00:00:01.000+08:00| 85.0|
|2025-05-13T00:00:02.000+08:00| 85.0|
|2025-05-13T00:00:03.000+08:00| 85.0|
|2025-05-13T00:00:04.000+08:00| 90.0|
|2025-05-13T00:00:05.000+08:00| 85.0|
|2025-05-13T00:00:06.000+08:00| 90.0|
+-----------------------------+-------+
```

**Example: Querying the downsampled data of table2:**

```SQL
IoTDB> SELECT date_bin_gapfill(1s, TIME) AS b_time,
first(humidity) AS b_value
FROM table2
WHERE device_id = 'd1'
AND TIME >= 2025-05-13 00:00:00.000
AND TIME <= 2025-05-13 00:00:07.000
GROUP BY 1 FILL METHOD PREVIOUS
```

**Result:**

```SQL
+-----------------------------+-------+
| b_time|b_value|
+-----------------------------+-------+
|2025-05-13T00:00:00.000+08:00| 35.1|
|2025-05-13T00:00:01.000+08:00| 37.2|
|2025-05-13T00:00:02.000+08:00| 37.2|
|2025-05-13T00:00:03.000+08:00| 35.2|
|2025-05-13T00:00:04.000+08:00| 38.2|
|2025-05-13T00:00:05.000+08:00| 35.4|
|2025-05-13T00:00:06.000+08:00| 35.1|
+-----------------------------+-------+
```

**Example: Aligning multiple sequences by integer time:**

```SQL
IoTDB> SELECT A.a_time AS TIME,
a_value,
b_value
FROM
(SELECT date_bin_gapfill(1s, TIME) AS a_time,
first(temperature) AS a_value
FROM table1
WHERE device_id = 'd1'
AND TIME >= 2025-05-13 00:00:00.000
AND TIME <= 2025-05-13 00:00:07.000
GROUP BY 1 FILL METHOD PREVIOUS) A
JOIN
(SELECT date_bin_gapfill(1s, TIME) AS b_time,
first(humidity) AS b_value
FROM table2
WHERE device_id = 'd1'
AND TIME >= 2025-05-13 00:00:00.000
AND TIME <= 2025-05-13 00:00:07.000
GROUP BY 1 FILL METHOD PREVIOUS) B
ON A.a_time=B.b_time
```

**Result:**

```SQL
+-----------------------------+-------+-------+
| time|a_value|b_value|
+-----------------------------+-------+-------+
|2025-05-13T00:00:00.000+08:00| 90.0| 35.1|
|2025-05-13T00:00:01.000+08:00| 85.0| 37.2|
|2025-05-13T00:00:02.000+08:00| 85.0| 37.2|
|2025-05-13T00:00:03.000+08:00| 85.0| 35.2|
|2025-05-13T00:00:04.000+08:00| 90.0| 38.2|
|2025-05-13T00:00:05.000+08:00| 85.0| 35.4|
|2025-05-13T00:00:06.000+08:00| 90.0| 35.1|
+-----------------------------+-------+-------+
```

- **Retaining NULL Values**: When NULL values have special significance or when you wish to preserve the null values in the data, you can choose to omit FILL METHOD PREVIOUS to avoid filling in the gaps.
**Example:**

```SQL
IoTDB> SELECT A.a_time AS TIME,
a_value,
b_value
FROM
(SELECT date_bin_gapfill(1s, TIME) AS a_time,
first(temperature) AS a_value
FROM table1
WHERE device_id = 'd1'
AND TIME >= 2025-05-13 00:00:00.000
AND TIME <= 2025-05-13 00:00:07.000
GROUP BY 1) A
JOIN
(SELECT date_bin_gapfill(1s, TIME) AS b_time,
first(humidity) AS b_value
FROM table2
WHERE device_id = 'd1'
AND TIME >= 2025-05-13 00:00:00.000
AND TIME <= 2025-05-13 00:00:07.000
GROUP BY 1) B
ON A.a_time=B.b_time
```

**Result:**

```SQL
+-----------------------------+-------+-------+
| time|a_value|b_value|
+-----------------------------+-------+-------+
|2025-05-13T00:00:00.000+08:00| 90.0| 35.1|
|2025-05-13T00:00:01.000+08:00| 85.0| 37.2|
|2025-05-13T00:00:02.000+08:00| 85.0| null|
|2025-05-13T00:00:03.000+08:00| null| 35.2|
|2025-05-13T00:00:04.000+08:00| 90.0| 38.2|
|2025-05-13T00:00:05.000+08:00| 85.0| 35.4|
|2025-05-13T00:00:06.000+08:00| 90.0| 35.1|
+-----------------------------+-------+-------+
```
#### 3.6.2 Different Sampling Frequencies, Different Times

**Table 1: Sampling Frequency: 1s**

| Time | device_id | temperature |
| ------------ | --------- | ----------- |
| 00:00:00.001 | d1 | 90.0 |
| 00:00:01.002 | d1 | 85.0 |
| 00:00:02.101 | d1 | 85.0 |
| 00:00:03.201 | d1 | null |
| 00:00:04.105 | d1 | 90.0 |
| 00:00:05.023 | d1 | 85.0 |
| 00:00:06.129 | d1 | 90.0 |

**Table 3: Sampling Frequency: 2s**

| Time | device_id | humidity |
| ------------ | --------- | -------- |
| 00:00:00.005 | d1 | 35.1 |
| 00:00:02.106 | d1 | 37.2 |
| 00:00:04.187 | d1 | null |
| 00:00:06.156 | d1 | 35.1 |

**Example: Querying the downsampled data of table1:**

```SQL
IoTDB> SELECT date_bin_gapfill(1s, TIME) AS a_time,
first(temperature) AS a_value
FROM table1
WHERE device_id = 'd1'
AND TIME >= 2025-05-13 00:00:00.000
AND TIME <= 2025-05-13 00:00:07.000
GROUP BY 1 FILL METHOD PREVIOUS
```

**Result:**

```SQL
+-----------------------------+-------+
| a_time|a_value|
+-----------------------------+-------+
|2025-05-13T00:00:00.000+08:00| 90.0|
|2025-05-13T00:00:01.000+08:00| 85.0|
|2025-05-13T00:00:02.000+08:00| 85.0|
|2025-05-13T00:00:03.000+08:00| 85.0|
|2025-05-13T00:00:04.000+08:00| 90.0|
|2025-05-13T00:00:05.000+08:00| 85.0|
|2025-05-13T00:00:06.000+08:00| 90.0|
+-----------------------------+-------+
```
**Example: Querying the downsampled data of table3:**

```SQL
IoTDB> SELECT date_bin_gapfill(1s, TIME) AS c_time,
first(humidity) AS c_value
FROM table3
WHERE device_id = 'd1'
AND TIME >= 2025-05-13 00:00:00.000
AND TIME <= 2025-05-13 00:00:07.000
GROUP BY 1 FILL METHOD PREVIOUS
```

**Result:**

```SQL
+-----------------------------+-------+
| c_time|c_value|
+-----------------------------+-------+
|2025-05-13T00:00:00.000+08:00| 35.1|
|2025-05-13T00:00:01.000+08:00| 35.1|
|2025-05-13T00:00:02.000+08:00| 37.2|
|2025-05-13T00:00:03.000+08:00| 37.2|
|2025-05-13T00:00:04.000+08:00| 37.2|
|2025-05-13T00:00:05.000+08:00| 37.2|
|2025-05-13T00:00:06.000+08:00| 35.1|
+-----------------------------+-------+
```

**Example: Aligning multiple sequences by the higher sampling frequency:**

```SQL
IoTDB> SELECT A.a_time AS TIME,
a_value,
c_value
FROM
(SELECT date_bin_gapfill(1s, TIME) AS a_time,
first(temperature) AS a_value
FROM table1
WHERE device_id = 'd1'
AND TIME >= 2025-05-13 00:00:00.000
AND TIME <= 2025-05-13 00:00:07.000
GROUP BY 1 FILL METHOD PREVIOUS) A
JOIN
(SELECT date_bin_gapfill(1s, TIME) AS c_time,
first(humidity) AS c_value
FROM table3
WHERE device_id = 'd1'
AND TIME >= 2025-05-13 00:00:00.000
AND TIME <= 2025-05-13 00:00:07.000
GROUP BY 1 FILL METHOD PREVIOUS) C
ON A.a_time=C.c_time
```

**Result:**

```SQL
+-----------------------------+-------+-------+
| time|a_value|c_value|
+-----------------------------+-------+-------+
|2025-05-13T00:00:00.000+08:00| 90.0| 35.1|
|2025-05-13T00:00:01.000+08:00| 85.0| 35.1|
|2025-05-13T00:00:02.000+08:00| 85.0| 37.2|
|2025-05-13T00:00:03.000+08:00| 85.0| 37.2|
|2025-05-13T00:00:04.000+08:00| 90.0| 37.2|
|2025-05-13T00:00:05.000+08:00| 85.0| 37.2|
|2025-05-13T00:00:06.000+08:00| 90.0| 35.1|
+-----------------------------+-------+-------+
```

### 3.6 Missing Data Filling
### 3.7 Missing Data Filling

**Example**: Query the records within a specified time range where `device_id` is '100'. If there are missing data points, fill them using the previous non-null value.

Expand Down Expand Up @@ -243,7 +528,7 @@ Total line number = 7
It costs 0.101s
```

### 3.7 Sorting & Pagination
### 3.8 Sorting & Pagination

**Example**: Query records from the table, sorting by `humidity` in descending order and placing null values (NULL) at the end. Skip the first 2 rows and return the next 8 rows.

Expand Down
Loading