diff --git a/src/.vuepress/public/img/sample_data.sql b/src/.vuepress/public/img/sample-data.sql similarity index 71% rename from src/.vuepress/public/img/sample_data.sql rename to src/.vuepress/public/img/sample-data.sql index 5e449d92d..b0c12e693 100644 --- a/src/.vuepress/public/img/sample_data.sql +++ b/src/.vuepress/public/img/sample-data.sql @@ -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'), @@ -47,8 +65,6 @@ 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'), @@ -56,4 +72,28 @@ INSERT INTO table1(region, plant_id, device_id, model_id, maintenance, time, tem ('上海', '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); diff --git a/src/UserGuide/Master/Table/Basic-Concept/Query-Data.md b/src/UserGuide/Master/Table/Basic-Concept/Query-Data.md index 05e53c4c3..007ecfba9 100644 --- a/src/UserGuide/Master/Table/Basic-Concept/Query-Data.md +++ b/src/UserGuide/Master/Table/Basic-Concept/Query-Data.md @@ -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. @@ -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. diff --git a/src/UserGuide/Master/Table/Reference/Sample-Data.md b/src/UserGuide/Master/Table/Reference/Sample-Data.md index 966de22c6..4235ff538 100644 --- a/src/UserGuide/Master/Table/Reference/Sample-Data.md +++ b/src/UserGuide/Master/Table/Reference/Sample-Data.md @@ -29,7 +29,7 @@ The structures of `table1` and `table2` are as follows: ## 2. Import Statements -Below are the SQL statements to create the above table structures and insert data. You can download the complete SQL script ([sample_data.sql](/img/sample_data.sql)) to execute these statements in the CLI to import the data into IoTDB. +Below are the SQL statements to create the above table structures and insert data. You can download the complete SQL script ([sample-data.sql](/img/sample-data.sql)) to execute these statements in the CLI to import the data into IoTDB. ```SQL -- Create a table with table names that are close to business semantics. Here, we use table1 instead diff --git a/src/UserGuide/Master/Table/SQL-Manual/Nested-Queries.md b/src/UserGuide/Master/Table/SQL-Manual/Nested-Queries.md index 031134efa..d0fa7cb47 100644 --- a/src/UserGuide/Master/Table/SQL-Manual/Nested-Queries.md +++ b/src/UserGuide/Master/Table/SQL-Manual/Nested-Queries.md @@ -874,3 +874,8 @@ Note: * For 50, 60, and 70, since `ANY` requires at least one comparison result to be `true` for the overall result to be `true`, and the comparison results with `null` are `null`, these results are `null`. * In the second query, because we have excluded null values, for 50, 60, and 70, there are no larger non-null values in `table3`, so the comparison results are `false`. +### 4.4 Non-Correlated Subqueries + +**Example:** + +* Downsampling queries for multiple sequences with misaligned timestamps. For detailed examples, see: [Example](../Basic-Concept/Query-Data.md#36-multi-sequence-downsampling-query-with-misaligned-timestamps) diff --git a/src/UserGuide/latest-Table/Basic-Concept/Query-Data.md b/src/UserGuide/latest-Table/Basic-Concept/Query-Data.md index 05e53c4c3..007ecfba9 100644 --- a/src/UserGuide/latest-Table/Basic-Concept/Query-Data.md +++ b/src/UserGuide/latest-Table/Basic-Concept/Query-Data.md @@ -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. @@ -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. diff --git a/src/UserGuide/latest-Table/Reference/Sample-Data.md b/src/UserGuide/latest-Table/Reference/Sample-Data.md index 966de22c6..4235ff538 100644 --- a/src/UserGuide/latest-Table/Reference/Sample-Data.md +++ b/src/UserGuide/latest-Table/Reference/Sample-Data.md @@ -29,7 +29,7 @@ The structures of `table1` and `table2` are as follows: ## 2. Import Statements -Below are the SQL statements to create the above table structures and insert data. You can download the complete SQL script ([sample_data.sql](/img/sample_data.sql)) to execute these statements in the CLI to import the data into IoTDB. +Below are the SQL statements to create the above table structures and insert data. You can download the complete SQL script ([sample-data.sql](/img/sample-data.sql)) to execute these statements in the CLI to import the data into IoTDB. ```SQL -- Create a table with table names that are close to business semantics. Here, we use table1 instead diff --git a/src/UserGuide/latest-Table/SQL-Manual/Nested-Queries.md b/src/UserGuide/latest-Table/SQL-Manual/Nested-Queries.md index 031134efa..b564c8780 100644 --- a/src/UserGuide/latest-Table/SQL-Manual/Nested-Queries.md +++ b/src/UserGuide/latest-Table/SQL-Manual/Nested-Queries.md @@ -874,3 +874,8 @@ Note: * For 50, 60, and 70, since `ANY` requires at least one comparison result to be `true` for the overall result to be `true`, and the comparison results with `null` are `null`, these results are `null`. * In the second query, because we have excluded null values, for 50, 60, and 70, there are no larger non-null values in `table3`, so the comparison results are `false`. +### 4.4 Non-Correlated Subqueries + +**Example:** + +* Downsampling queries for multiple sequences with misaligned timestamps. For detailed examples, see: [Example](../Basic-Concept/Query-Data.md#36-multi-sequence-downsampling-query-with-misaligned-timestamps) \ No newline at end of file diff --git a/src/zh/UserGuide/Master/Table/Basic-Concept/Query-Data.md b/src/zh/UserGuide/Master/Table/Basic-Concept/Query-Data.md index 0468da5a5..3ceb09703 100644 --- a/src/zh/UserGuide/Master/Table/Basic-Concept/Query-Data.md +++ b/src/zh/UserGuide/Master/Table/Basic-Concept/Query-Data.md @@ -188,33 +188,319 @@ Total line number = 2 It costs 0.090s ``` -### 3.5 降采样查询(date_bin_gapfill函数) +### 3.5 降采样查询(date_bin 函数) **示例:查询将时间按天分组,并计算每天的平均温度。** ```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); ``` 执行结果如下: ```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 时间戳不对齐的多序列降采样查询 + +#### 3.6.1 采样频率相同,时间不同 + +**table1:采样频率: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 | + +**table2:采样频率: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 | + +**示例:查询`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 +``` + +**结果:** + +```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| ++-----------------------------+-------+ +``` + +**示例:查询`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 +``` + +**结果:** + +```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| ++-----------------------------+-------+ +``` + +**示例:按整点将多个序列进行时间对齐:** + +```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 +``` + +**结果:** + +```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| ++-----------------------------+-------+-------+ +``` + +- 保留空值:当 `NULL` 值本身具有特殊含义,或希望保留数据的 null 值时,可以选择去掉 `FILL METHOD PREVIOUS` 不进行填充。 +**示例:** + +```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 +``` + +**结果:** + +```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 采样频率不同,时间不同 + +**table1:采样频率: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 | + +**table3: 采样频率: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 | + +**示例:查询`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 +``` + +**结果:** + +```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| ++-----------------------------+-------+ +``` +**示例:查询`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 +``` + +**结果:** + +```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| ++-----------------------------+-------+ +``` + +**示例:按照高采样频率进行对齐:** + +```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 +``` + +**结果:** + +```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 数据填充 +### 3.7 数据填充 **示例:查询指定时间范围内,满足 `device_id` 为 '100' 的记录,若存在缺失的数据点,则用前一个非空值进行填充。** @@ -244,7 +530,7 @@ Total line number = 7 It costs 0.101s ``` -### 3.7 排序&分页 +### 3.8 排序&分页 **示例:查询表中湿度降序排列且空值(NULL)排最后的记录,跳过前 2 条,只返回接下来的 8 条记录。** diff --git a/src/zh/UserGuide/Master/Table/Reference/Sample-Data.md b/src/zh/UserGuide/Master/Table/Reference/Sample-Data.md index 24f85071f..514ccc5c8 100644 --- a/src/zh/UserGuide/Master/Table/Reference/Sample-Data.md +++ b/src/zh/UserGuide/Master/Table/Reference/Sample-Data.md @@ -31,7 +31,7 @@ table1和table2均为如下表结构: ## 2. 导入语句 -以下为构建上述表结构及数据的SQL语句,您可以点此([sample_data.sql](/img/sample_data.sql))下载全部SQL并在CLI中执行,从而将数据导入您的IoTDB。 +以下为构建上述表结构及数据的SQL语句,您可以点此([sample-data.sql](/img/sample-data.sql))下载全部SQL并在CLI中执行,从而将数据导入您的IoTDB。 ```SQL -- 创建表,表名可以贴近业务语义,这里我们以 table1 来代替 diff --git a/src/zh/UserGuide/Master/Table/SQL-Manual/Nested-Queries.md b/src/zh/UserGuide/Master/Table/SQL-Manual/Nested-Queries.md index c855fbfb3..f989585ff 100644 --- a/src/zh/UserGuide/Master/Table/SQL-Manual/Nested-Queries.md +++ b/src/zh/UserGuide/Master/Table/SQL-Manual/Nested-Queries.md @@ -873,3 +873,8 @@ IoTDB> SELECT s1 <= * 对于 50、60、70,由于`ANY`要求的是至少一个比较结果为`true`结果就是`true`,而与`null`的比较结果为`null`,所以这些结果为`null`。 * 在第二个查询中,由于我们排除了空值,所以对于 50、60、70,由于`table3`中没有更大的非空值,比较结果为`false`。 +### 4.4 非关联表子查询 + +**示例:** + +* 时间戳不对齐的多序列降采样查询,详细示例可见:[示例](../Basic-Concept/Query-Data.md#36-时间戳不对齐的多序列降采样查询) \ No newline at end of file diff --git a/src/zh/UserGuide/latest-Table/Basic-Concept/Query-Data.md b/src/zh/UserGuide/latest-Table/Basic-Concept/Query-Data.md index 0468da5a5..3ceb09703 100644 --- a/src/zh/UserGuide/latest-Table/Basic-Concept/Query-Data.md +++ b/src/zh/UserGuide/latest-Table/Basic-Concept/Query-Data.md @@ -188,33 +188,319 @@ Total line number = 2 It costs 0.090s ``` -### 3.5 降采样查询(date_bin_gapfill函数) +### 3.5 降采样查询(date_bin 函数) **示例:查询将时间按天分组,并计算每天的平均温度。** ```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); ``` 执行结果如下: ```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 时间戳不对齐的多序列降采样查询 + +#### 3.6.1 采样频率相同,时间不同 + +**table1:采样频率: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 | + +**table2:采样频率: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 | + +**示例:查询`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 +``` + +**结果:** + +```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| ++-----------------------------+-------+ +``` + +**示例:查询`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 +``` + +**结果:** + +```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| ++-----------------------------+-------+ +``` + +**示例:按整点将多个序列进行时间对齐:** + +```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 +``` + +**结果:** + +```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| ++-----------------------------+-------+-------+ +``` + +- 保留空值:当 `NULL` 值本身具有特殊含义,或希望保留数据的 null 值时,可以选择去掉 `FILL METHOD PREVIOUS` 不进行填充。 +**示例:** + +```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 +``` + +**结果:** + +```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 采样频率不同,时间不同 + +**table1:采样频率: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 | + +**table3: 采样频率: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 | + +**示例:查询`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 +``` + +**结果:** + +```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| ++-----------------------------+-------+ +``` +**示例:查询`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 +``` + +**结果:** + +```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| ++-----------------------------+-------+ +``` + +**示例:按照高采样频率进行对齐:** + +```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 +``` + +**结果:** + +```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 数据填充 +### 3.7 数据填充 **示例:查询指定时间范围内,满足 `device_id` 为 '100' 的记录,若存在缺失的数据点,则用前一个非空值进行填充。** @@ -244,7 +530,7 @@ Total line number = 7 It costs 0.101s ``` -### 3.7 排序&分页 +### 3.8 排序&分页 **示例:查询表中湿度降序排列且空值(NULL)排最后的记录,跳过前 2 条,只返回接下来的 8 条记录。** diff --git a/src/zh/UserGuide/latest-Table/Reference/Sample-Data.md b/src/zh/UserGuide/latest-Table/Reference/Sample-Data.md index 24f85071f..f76416397 100644 --- a/src/zh/UserGuide/latest-Table/Reference/Sample-Data.md +++ b/src/zh/UserGuide/latest-Table/Reference/Sample-Data.md @@ -31,7 +31,7 @@ table1和table2均为如下表结构: ## 2. 导入语句 -以下为构建上述表结构及数据的SQL语句,您可以点此([sample_data.sql](/img/sample_data.sql))下载全部SQL并在CLI中执行,从而将数据导入您的IoTDB。 +以下为构建上述表结构及数据的SQL语句,您可以点此([sample-data.sql](/img/sample-data.sql))下载全部SQL并在CLI中执行,从而将数据导入您的IoTDB。 ```SQL -- 创建表,表名可以贴近业务语义,这里我们以 table1 来代替 @@ -65,6 +65,23 @@ 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 @@ -94,4 +111,28 @@ INSERT INTO table1(region, plant_id, device_id, model_id, maintenance, time, tem ('上海', '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); ``` \ No newline at end of file diff --git a/src/zh/UserGuide/latest-Table/SQL-Manual/Nested-Queries.md b/src/zh/UserGuide/latest-Table/SQL-Manual/Nested-Queries.md index c855fbfb3..f989585ff 100644 --- a/src/zh/UserGuide/latest-Table/SQL-Manual/Nested-Queries.md +++ b/src/zh/UserGuide/latest-Table/SQL-Manual/Nested-Queries.md @@ -873,3 +873,8 @@ IoTDB> SELECT s1 <= * 对于 50、60、70,由于`ANY`要求的是至少一个比较结果为`true`结果就是`true`,而与`null`的比较结果为`null`,所以这些结果为`null`。 * 在第二个查询中,由于我们排除了空值,所以对于 50、60、70,由于`table3`中没有更大的非空值,比较结果为`false`。 +### 4.4 非关联表子查询 + +**示例:** + +* 时间戳不对齐的多序列降采样查询,详细示例可见:[示例](../Basic-Concept/Query-Data.md#36-时间戳不对齐的多序列降采样查询) \ No newline at end of file