diff --git a/src/UserGuide/Master/Table/SQL-Manual/From-Join-Clause.md b/src/UserGuide/Master/Table/SQL-Manual/From-Join-Clause.md index eb437981c..ceaa9d70e 100644 --- a/src/UserGuide/Master/Table/SQL-Manual/From-Join-Clause.md +++ b/src/UserGuide/Master/Table/SQL-Manual/From-Join-Clause.md @@ -33,7 +33,7 @@ relation joinType : INNER? - | FULL OUTER? + | OUTER? | CROSS? | ASOF? ; @@ -72,8 +72,8 @@ The `JOIN` clause combines two tables based on specific conditions, typically pr In the current version of IoTDB, the following joins are supported: -1. **Inner Join**: Combines rows that meet the join condition, effectively returning the intersection of the two tables. The join condition must be an equality condition on the `time` column. -2. **Full Outer Join**: Returns all records from both tables, inserting `NULL` values for unmatched rows. The join condition can be any equality expression. +1. **Inner Join**: The join condition can be any equality expression. +2. **Outer Join**: The join condition can be any equality expression. 3. **Cross Join**: Represents the Cartesian product of two tables. 4. ​**​ASOF JOIN​​** (AS OF a specific point in time) is a specialized join operation based on temporal or approximate matching conditions, designed for scenarios where timestamps between two datasets are not perfectly aligned. It matches each row from the left table with the closest corresponding row in the right table that meets the specified conditions (typically the nearest preceding or succeeding timestamp). This operation is widely used for time-series data analysis (e.g., sensor data, financial market feeds). @@ -120,7 +120,47 @@ An **outer join** returns rows even when no matching records exist in the other - **RIGHT OUTER JOIN**: Returns all rows from the right table. - **FULL OUTER JOIN**: Returns all rows from both tables. -IoTDB currently supports only `FULL [OUTER] JOIN`. This type returns all records from both tables. If a record in one table has no match in the other, `NULL` values are returned for the unmatched fields. `FULL JOIN` **must use explicit join conditions**. +#### 3.2.1 Left Outer Join + +LEFT [OUTER] JOIN (i.e., left outer join) returns all records from the left table, along with the records from the right table that satisfy the join condition with the left table. For records in the right table that have no matching entries in the left table, NULL values are returned. Since the LEFT JOIN keyword must be specified, left outer join typically uses only the explicit join syntax, where the join condition is specified after ON or USING. + +> Supported in V2.0.5 and later versions + +The SQL syntax is as follows: + +```SQL +-- Explicit join: specify the join condition after the ON keyword or join columns after the USING keyword +SELECT selectExpr [, selectExpr] ... FROM LEFT [OUTER] JOIN joinCriteria [WHERE whereCondition] + +joinCriteria + : ON booleanExpression + | USING '(' identifier (',' identifier)* ')' + ; +``` + +#### 3.2.2 Right Outer Join + +RIGHT [OUTER] JOIN (i.e., right outer join) returns all records from the right table, along with the records from the left table that satisfy the join condition with the right table. For records in the left table that have no matching entries in the right table, NULL values are returned. + +> Supported in V2.0.5 and later versions + +RIGHT JOIN is a "symmetric" operation to LEFT JOIN. In practice, `LEFT JOIN` is more commonly used because we usually care more about the data in the left table in real-world applications. Furthermore, `RIGHT JOIN` can always be converted to `LEFT JOIN` — the query result of `A RIGHT JOIN B ON A.id=B.id` is equivalent to that of `B LEFT JOIN A ON B.id = A.id`. + +The SQL syntax is as follows: + +```SQL +-- Specify the join condition after the ON keyword or join columns after the USING keyword +SELECT selectExpr [, selectExpr] ... FROM RIGHT [OUTER] JOIN joinCriteria [WHERE whereCondition] + +joinCriteria + : ON booleanExpression + | USING '(' identifier (',' identifier)* ')' + ; +``` + +#### 3.2.3 Full Outer Join + +FULL [OUTER] JOIN (i.e., full outer join) returns all records from both tables. If a record in one table has no match in the other, `NULL` values are returned for the unmatched fields. `FULL JOIN` **must use explicit join conditions**. ```sql //Specify the join condition after the ON keyword or specify the join columns after the USING keyword. @@ -137,13 +177,15 @@ A cross join represents the Cartesian product of two tables, returning all possi ### 3.4 ​Asof Join -IoTDB ASOF JOIN is an approximate point join method that allows users to perform matching based on the closest timestamp according to specified rules. ​​The current version only supports ASOF INNER JOIN for Time columns.​​ +IoTDB ASOF JOIN is an approximate point join method that allows users to perform matching based on the closest timestamp according to specified rules. ​​The current version only supports ASOF INNER/LEFT JOIN.​​ + +> ASOF LEFT JOIN supported in V2.0.5 and later versions The SQL syntax is as follows: ```SQL SELECT selectExpr [, selectExpr] ... FROM - ASOF[(tolerance theta)] [INNER] JOIN joinCriteria + ASOF[(tolerance theta)] [INNER|LEFT] JOIN joinCriteria [WHERE whereCondition] WHERE a.time = tolerance(b.time, 1s) @@ -159,7 +201,7 @@ comparisonOperator **​Notes:​​** * ASOF JOIN defaults to ASOF INNER JOIN implementation. -* When using the ON keyword for joining, the join condition must include an inequality join condition for the Time column. Only four operators are supported: `">", ">=", "<", "<="`. The corresponding join matching rules are as follows (where lt represents the left table and rt represents the right table): +* When using the ON keyword for joining, the join condition must include an inequality join condition where both the left and right sides are of TIMESTAMP type (i.e., the primary join condition). Only four operators are supported: `">", ">=", "<", "<="`. The corresponding join matching rules are as follows (where lt represents the left table and rt represents the right table): | Operator | Join Method | | -------------------------- | ---------------------------------------------- | @@ -169,6 +211,51 @@ comparisonOperator | `lt.time < rt.time` | The closest timestamp in the left table that is less than the right table's timestamp. | * `Tolerance parameter​`​: The maximum allowed time difference for searching data in the right table (expressed as a TimeDuration, e.g., 1d for one day). If the Tolerance parameter is not specified, the search time range defaults to ​​infinity​​. ​​Note​​: Currently, this parameter is only supported in ASOF ​​INNER​​ JOIN. +* In addition to the primary join condition, ASOF can also specify equality join conditions for other columns (ID, Attribute, Measurement), which means the query results are grouped by these other columns. The primary join condition must be placed ​**last**​, and it must be connected to other conditions (if any) using "AND". + +### 3.5 Semi Join/Anti-Semi Join + +A semi join is a special join operation whose purpose is to determine whether rows in one table exist in another table. The result set returned by a semi join contains rows from the first table that meet the join condition, but does not include the actual data from the second table. Corresponding to semi join is anti-semi join, which is used to identify rows that have no matches between two tables. The result set returned by an anti-semi join contains rows from the first table that satisfy the join condition, but excludes rows from the second table that match those rows. + +In the IoTDB table model, the `SEMI JOIN` syntax is not provided; instead, IN subqueries or EXISTS subqueries are supported to implement semi joins. Similarly, the `ANTI SEMI JOIN` syntax is not provided, and NOT IN or NOT EXISTS subqueries are supported to implement anti-semi joins. For detailed explanations of subqueries, refer to [Nested Queries](../SQL-Manual/Nested-Queries.md). + +* Examples of semi join syntax are as follows: + +```SQL +-- Implement semi join using IN +SELECT * +FROM table1 +WHERE time IN (SELECT time FROM table2); + +-- Implement semi join using EXISTS +SELECT * +FROM table1 t1 +WHERE EXISTS (SELECT 1 FROM table2 t2 WHERE t1.time = t2.time); + +-- Equivalent to the SEMI JOIN syntax in other databases +SELECT table1.* +FROM table1 SEMI JOIN table2 +ON table1.time=table2.time; +``` + +* Examples of anti-semi join syntax are as follows: + +```SQL +-- Implement anti-semi join using NOT IN +SELECT * +FROM table1 +WHERE time NOT IN (SELECT time FROM table2); + +-- Implement anti-semi join using NOT EXISTS +SELECT * +FROM table1 t1 +WHERE NOT EXISTS (SELECT 1 FROM table2 t2 WHERE t1.time = t2.time); + +-- Equivalent to the ANTI SEMI JOIN syntax in other databases +SELECT table1.* +FROM table1 ANTI JOIN table2 +ON table1.time=table2.time; +``` @@ -192,24 +279,24 @@ Query Results: +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ | time|region|plant_id|device_id|model_id|maintenance|temperature|humidity|status| arrival_time| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ -|2024-11-26T13:37:00.000+08:00| 北京| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:37:34.000+08:00| -|2024-11-26T13:38:00.000+08:00| 北京| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:38:25.000+08:00| -|2024-11-27T16:38:00.000+08:00| 北京| 1001| 101| B| 180| null| 35.1| true|2024-11-27T16:37:01.000+08:00| -|2024-11-27T16:39:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| 35.3| null| null| -|2024-11-27T16:40:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:03.000+08:00| -|2024-11-27T16:41:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:04.000+08:00| -|2024-11-27T16:42:00.000+08:00| 北京| 1001| 101| B| 180| null| 35.2| false| null| -|2024-11-27T16:43:00.000+08:00| 北京| 1001| 101| B| 180| null| null| false| null| -|2024-11-27T16:44:00.000+08:00| 北京| 1001| 101| B| 180| null| null| false|2024-11-27T16:37:08.000+08:00| -|2024-11-28T08:00:00.000+08:00| 上海| 3001| 100| C| 90| 85.0| null| null|2024-11-28T08:00:09.000+08:00| -|2024-11-28T09:00:00.000+08:00| 上海| 3001| 100| C| 90| null| 40.9| true| null| -|2024-11-28T10:00:00.000+08:00| 上海| 3001| 100| C| 90| 85.0| 35.2| null|2024-11-28T10:00:11.000+08:00| -|2024-11-28T11:00:00.000+08:00| 上海| 3001| 100| C| 90| 88.0| 45.1| true|2024-11-28T11:00:12.000+08:00| -|2024-11-29T10:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| null| null|2024-11-29T10:00:13.000+08:00| -|2024-11-29T11:00:00.000+08:00| 上海| 3002| 100| E| 180| null| 45.1| true| null| -|2024-11-29T18:30:00.000+08:00| 上海| 3002| 100| E| 180| 90.0| 35.4| true|2024-11-29T18:30:15.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| -|2024-11-30T14:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00| +|2024-11-26T13:37:00.000+08:00| BJ| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:37:34.000+08:00| +|2024-11-26T13:38:00.000+08:00| BJ| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:38:25.000+08:00| +|2024-11-27T16:38:00.000+08:00| BJ| 1001| 101| B| 180| null| 35.1| true|2024-11-27T16:37:01.000+08:00| +|2024-11-27T16:39:00.000+08:00| BJ| 1001| 101| B| 180| 85.0| 35.3| null| null| +|2024-11-27T16:40:00.000+08:00| BJ| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:03.000+08:00| +|2024-11-27T16:41:00.000+08:00| BJ| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:04.000+08:00| +|2024-11-27T16:42:00.000+08:00| BJ| 1001| 101| B| 180| null| 35.2| false| null| +|2024-11-27T16:43:00.000+08:00| BJ| 1001| 101| B| 180| null| null| false| null| +|2024-11-27T16:44:00.000+08:00| BJ| 1001| 101| B| 180| null| null| false|2024-11-27T16:37:08.000+08:00| +|2024-11-28T08:00:00.000+08:00| SH| 3001| 100| C| 90| 85.0| null| null|2024-11-28T08:00:09.000+08:00| +|2024-11-28T09:00:00.000+08:00| SH| 3001| 100| C| 90| null| 40.9| true| null| +|2024-11-28T10:00:00.000+08:00| SH| 3001| 100| C| 90| 85.0| 35.2| null|2024-11-28T10:00:11.000+08:00| +|2024-11-28T11:00:00.000+08:00| SH| 3001| 100| C| 90| 88.0| 45.1| true|2024-11-28T11:00:12.000+08:00| +|2024-11-29T10:00:00.000+08:00| SH| 3001| 101| D| 360| 85.0| null| null|2024-11-29T10:00:13.000+08:00| +|2024-11-29T11:00:00.000+08:00| SH| 3002| 100| E| 180| null| 45.1| true| null| +|2024-11-29T18:30:00.000+08:00| SH| 3002| 100| E| 180| 90.0| 35.4| true|2024-11-29T18:30:15.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null| +|2024-11-30T14:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ Total line number = 18 It costs 0.085s @@ -227,16 +314,16 @@ Query Results: +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ | time|region|plant_id|device_id|model_id|maintenance|temperature|humidity|status| arrival_time| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ -|2024-11-27T16:38:00.000+08:00| 北京| 1001| 101| B| 180| null| 35.1| true|2024-11-27T16:37:01.000+08:00| -|2024-11-27T16:39:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| 35.3| null| null| -|2024-11-27T16:40:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:03.000+08:00| -|2024-11-27T16:41:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:04.000+08:00| -|2024-11-27T16:42:00.000+08:00| 北京| 1001| 101| B| 180| null| 35.2| false| null| -|2024-11-27T16:43:00.000+08:00| 北京| 1001| 101| B| 180| null| null| false| null| -|2024-11-27T16:44:00.000+08:00| 北京| 1001| 101| B| 180| null| null| false|2024-11-27T16:37:08.000+08:00| -|2024-11-29T10:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| null| null|2024-11-29T10:00:13.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| -|2024-11-30T14:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00| +|2024-11-27T16:38:00.000+08:00| BJ| 1001| 101| B| 180| null| 35.1| true|2024-11-27T16:37:01.000+08:00| +|2024-11-27T16:39:00.000+08:00| BJ| 1001| 101| B| 180| 85.0| 35.3| null| null| +|2024-11-27T16:40:00.000+08:00| BJ| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:03.000+08:00| +|2024-11-27T16:41:00.000+08:00| BJ| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:04.000+08:00| +|2024-11-27T16:42:00.000+08:00| BJ| 1001| 101| B| 180| null| 35.2| false| null| +|2024-11-27T16:43:00.000+08:00| BJ| 1001| 101| B| 180| null| null| false| null| +|2024-11-27T16:44:00.000+08:00| BJ| 1001| 101| B| 180| null| null| false|2024-11-27T16:37:08.000+08:00| +|2024-11-29T10:00:00.000+08:00| SH| 3001| 101| D| 360| 85.0| null| null|2024-11-29T10:00:13.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null| +|2024-11-30T14:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ Total line number = 10 It costs 0.061s @@ -355,8 +442,273 @@ Total line number = 3 It costs 0.082s ``` +**Example 4: Equality Join on Non-time Columns** + +```SQL +SELECT + t1.time, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 JOIN table2 t2 +ON t1.device_id = t2.device_id +ORDER BY t1.time +LIMIT 10 +``` + +Query Results: + +```SQL ++-----------------------------+-------+------------+-------+------------+ +| time|device1|temperature1|device2|temperature2| ++-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| null| +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 85.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| 100| null| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| 100| 85.0| +|2024-11-27T16:38:00.000+08:00| 101| null| 101| 90.0| +|2024-11-27T16:38:00.000+08:00| 101| null| 101| 85.0| +|2024-11-27T16:38:00.000+08:00| 101| null| 101| 85.0| +|2024-11-27T16:39:00.000+08:00| 101| 85.0| 101| 90.0| ++-----------------------------+-------+------------+-------+------------+ +Total line number = 10 +It costs 0.030s +``` + + + #### 4.2.2 Outer Join +1. LEFT JOIN + +**Example 1: Explicit Join** + +```SQL +SELECT + t1.time as time1, t2.time as time2, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 LEFT JOIN table2 t2 +ON t1.time = t2.time +``` + +Query Results: + +```SQL ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +| time1| time2|device1|temperature1|device2|temperature2| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| null| 100| 90.0| null| null| +|2024-11-27T16:38:00.000+08:00| null| 101| null| null| null| +|2024-11-27T16:39:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-27T16:40:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-27T16:41:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-27T16:42:00.000+08:00| null| 101| null| null| null| +|2024-11-27T16:43:00.000+08:00| null| 101| null| null| null| +|2024-11-27T16:44:00.000+08:00| null| 101| null| null| null| +|2024-11-28T08:00:00.000+08:00|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +|2024-11-28T09:00:00.000+08:00| null| 100| null| null| null| +|2024-11-28T10:00:00.000+08:00| null| 100| 85.0| null| null| +|2024-11-28T11:00:00.000+08:00| null| 100| 88.0| null| null| +|2024-11-29T10:00:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-29T11:00:00.000+08:00|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +|2024-11-29T18:30:00.000+08:00| null| 100| 90.0| null| null| +|2024-11-30T09:30:00.000+08:00| null| 101| 90.0| null| null| +|2024-11-30T14:30:00.000+08:00| null| 101| 90.0| null| null| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +Total line number = 18 +It costs 0.031s +``` + +**Example 2: Explicit Join** + +```SQL +SELECT + time, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 LEFT JOIN table2 t2 +USING(time) +``` + +Query Results: + +```SQL ++-----------------------------+-------+------------+-------+------------+ +| time|device1|temperature1|device2|temperature2| ++-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| null| null| +|2024-11-27T16:38:00.000+08:00| 101| null| null| null| +|2024-11-27T16:39:00.000+08:00| 101| 85.0| null| null| +|2024-11-27T16:40:00.000+08:00| 101| 85.0| null| null| +|2024-11-27T16:41:00.000+08:00| 101| 85.0| null| null| +|2024-11-27T16:42:00.000+08:00| 101| null| null| null| +|2024-11-27T16:43:00.000+08:00| 101| null| null| null| +|2024-11-27T16:44:00.000+08:00| 101| null| null| null| +|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +|2024-11-28T09:00:00.000+08:00| 100| null| null| null| +|2024-11-28T10:00:00.000+08:00| 100| 85.0| null| null| +|2024-11-28T11:00:00.000+08:00| 100| 88.0| null| null| +|2024-11-29T10:00:00.000+08:00| 101| 85.0| null| null| +|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +|2024-11-29T18:30:00.000+08:00| 100| 90.0| null| null| +|2024-11-30T09:30:00.000+08:00| 101| 90.0| null| null| +|2024-11-30T14:30:00.000+08:00| 101| 90.0| null| null| ++-----------------------------+-------+------------+-------+------------+ +Total line number = 18 +It costs 0.031s +``` + +**Example 3: Join Condition on Non-time Column** + +```SQL +SELECT + region, + t1.time as time1, + t1.temperature as temperature1, + t2.time as time2, + t2.temperature as temperature2 +FROM + table1 t1 LEFT JOIN table2 t2 +USING(region) +LIMIT 10 +``` + +Query Results: + +```SQL ++------+-----------------------------+------------+-----------------------------+------------+ +|region| time1|temperature1| time2|temperature2| ++------+-----------------------------+------------+-----------------------------+------------+ +|Shanghai|2024-11-29T11:00:00.000+08:00| null|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-29T11:00:00.000+08:00| null|2024-11-28T08:00:00.000+08:00| 85.0| +|Shanghai|2024-11-29T11:00:00.000+08:00| null|2024-11-30T00:00:00.000+08:00| 90.0| +|Shanghai|2024-11-29T11:00:00.000+08:00| null|2024-11-29T00:00:00.000+08:00| 85.0| +|Shanghai|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-28T08:00:00.000+08:00| 85.0| +|Shanghai|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-30T00:00:00.000+08:00| 90.0| +|Shanghai|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-29T00:00:00.000+08:00| 85.0| +|Shanghai|2024-11-29T18:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-29T18:30:00.000+08:00| 90.0|2024-11-28T08:00:00.000+08:00| 85.0| ++------+-----------------------------+------------+-----------------------------+------------+ +Total line number = 10 +It costs 0.038s +``` + +2. RIGHT JOIN + +**Example 1: Explicit Join** + +```SQL +SELECT + t1.time as time1, t2.time as time2, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 RIGHT JOIN table2 t2 +ON t1.time = t2.time +``` + +Query Results: + +```SQL ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +| time1| time2|device1|temperature1|device2|temperature2| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +| null|2024-11-27T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-28T08:00:00.000+08:00|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +| null|2024-11-29T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-29T11:00:00.000+08:00|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +| null|2024-11-30T00:00:00.000+08:00| null| null| 101| 90.0| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +Total line number = 6 +It costs 0.030s +``` + +**Example 2: Explicit Join** + +```SQL +SELECT + time, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 RIGHT JOIN table2 t2 +USING(time) +``` + +Query Results: + +```SQL ++-----------------------------+-------+------------+-------+------------+ +| time|device1|temperature1|device2|temperature2| ++-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-27T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +|2024-11-29T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +|2024-11-30T00:00:00.000+08:00| null| null| 101| 90.0| ++-----------------------------+-------+------------+-------+------------+ +Total line number = 6 +It costs 0.053s +``` + +**Example 3: Join Condition on Non-time Column** + +```SQL +SELECT + region, + t1.time as time1, + t1.temperature as temperature1, + t2.time as time2, + t2.temperature as temperature2 +FROM + table1 t1 RIGHT JOIN table2 t2 +USING(region) +LIMIT 10 +``` + +Query Results: + +```SQL ++------+-----------------------------+------------+-----------------------------+------------+ +|region| time1|temperature1| time2|temperature2| ++------+-----------------------------+------------+-----------------------------+------------+ +|Shanghai|2024-11-29T11:00:00.000+08:00| null|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-29T18:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-28T08:00:00.000+08:00| 85.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-30T14:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-29T10:00:00.000+08:00| 85.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-28T09:00:00.000+08:00| null|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-28T10:00:00.000+08:00| 85.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-28T11:00:00.000+08:00| 88.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-29T11:00:00.000+08:00| null|2024-11-28T08:00:00.000+08:00| 85.0| ++------+-----------------------------+------------+-----------------------------+------------+ +Total line number = 10 +It costs 0.029s +``` + +3. FULL JOIN + **Example 1: Full Outer Join using `ON`** This query retrieves all records from `table1` and `table2`, including unmatched rows with `NULL` values. @@ -503,14 +855,14 @@ Query Results: +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ | time|region|plant_id|device_id|model_id|maintenance|temperature|humidity|status| arrival_time| time|region|plant_id|device_id|model_id|maintenance|temperature|humidity|status| arrival_time| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-27T00:00:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| 35.1| true|2024-11-27T16:37:01.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T11:00:00.000+08:00| 上海| 3002| 100| E| 180| null| 45.1| true| null| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-28T08:00:00.000+08:00| 上海| 3001| 100| C| 90| 85.0| 35.2| false|2024-11-28T08:00:09.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-26T13:37:00.000+08:00| 北京| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:37:34.000+08:00| -|2024-11-30T14:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| -|2024-11-30T14:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-27T00:00:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| 35.1| true|2024-11-27T16:37:01.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T11:00:00.000+08:00| 上海| 3002| 100| E| 180| null| 45.1| true| null| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-28T08:00:00.000+08:00| 上海| 3001| 100| C| 90| 85.0| 35.2| false|2024-11-28T08:00:09.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-26T13:37:00.000+08:00| 北京| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:37:34.000+08:00| +|2024-11-30T14:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| +|2024-11-30T14:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ Total line number = 8 It costs 0.282s @@ -528,14 +880,14 @@ Query Results: +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ | time|region|plant_id|device_id|model_id|maintenance|temperature|humidity|status| arrival_time| time|region|plant_id|device_id|model_id|maintenance|temperature|humidity|status| arrival_time| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-27T00:00:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| 35.1| true|2024-11-27T16:37:01.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T11:00:00.000+08:00| 上海| 3002| 100| E| 180| null| 45.1| true| null| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-28T08:00:00.000+08:00| 上海| 3001| 100| C| 90| 85.0| 35.2| false|2024-11-28T08:00:09.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-26T13:37:00.000+08:00| 北京| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:37:34.000+08:00| -|2024-11-30T14:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| -|2024-11-30T14:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-27T00:00:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| 35.1| true|2024-11-27T16:37:01.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T11:00:00.000+08:00| 上海| 3002| 100| E| 180| null| 45.1| true| null| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-28T08:00:00.000+08:00| 上海| 3001| 100| C| 90| 85.0| 35.2| false|2024-11-28T08:00:09.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-26T13:37:00.000+08:00| 北京| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:37:34.000+08:00| +|2024-11-30T14:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| +|2024-11-30T14:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ Total line number = 8 It costs 0.047s @@ -543,6 +895,8 @@ It costs 0.047s #### 4.2.4 Asof join +1. ASOF INNER JOIN + ​​Example 1​​: Without specifying the tolerance parameter, where the timestamp in table1 is greater than or equal to and closest to the timestamp in table2. ```SQL @@ -593,3 +947,121 @@ Query Results: |2024-11-26T13:37:00.000+08:00| 100| 90.0|2024-11-26T13:37:00.000+08:00| 100| 90.0| +-----------------------------+-------+------------+-----------------------------+-------+------------+ ``` + +**Example 3: Tolerance Parameter Specified, plant\_id is the Same, and the Timestamp in table1 is Greater Than or Equal to That in table2 with the Closest Timestamp** + +```SQL +SELECT t1.time as time1, t1.plant_id as plant1, t1.temperature as temperature1, t2.time as time2, t2.plant_id as plant2, t2.temperature as temperature2 FROM table1 t1 ASOF(tolerance 2s) JOIN table2 t2 ON t1.plant_id=t2.plant_id and t1.time>=t2.time; +``` + +Query Results + +```SQL ++-----------------------------+------+------------+-----------------------------+------+------------+ +| time1|plant1|temperature1| time2|plant2|temperature2| ++-----------------------------+------+------------+-----------------------------+------+------------+ +|2024-11-26T13:37:00.000+08:00| 1001| 90.0|2024-11-26T13:37:00.000+08:00| 1001| 90.0| +|2024-11-28T08:00:00.000+08:00| 3001| 85.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-29T11:00:00.000+08:00| 3002| null|2024-11-29T11:00:00.000+08:00| 3002| null| ++-----------------------------+------+------------+-----------------------------+------+------------+ +Total line number = 3 +It costs 0.046s +``` + +**Example 4: Asof Join Between a Time Period Today and the Corresponding Time Period Last Week** + +```SQL +SELECT * FROM (SELECT time, device_id AS device1, temperature AS temperature1 FROM table1 ) AS t1 ASOF JOIN (SELECT time, device_id AS device2, temperature AS temperature2 FROM table1) AS t2 ON t1.time>date_bin(1w, t2.time) limit 10 +``` + +Query Results: + +```SQL ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +| time|device1|temperature1| time|device2|temperature2| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-29T11:00:00.000+08:00| 100| null| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-30T09:30:00.000+08:00| 101| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-29T18:30:00.000+08:00| 100| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-30T14:30:00.000+08:00| 101| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-29T10:00:00.000+08:00| 101| 85.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T09:00:00.000+08:00| 100| null| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T10:00:00.000+08:00| 100| 85.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T11:00:00.000+08:00| 100| 88.0| +|2024-11-30T09:30:00.000+08:00| 101| 90.0|2024-11-29T11:00:00.000+08:00| 100| null| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +``` + +2. ASOF LEFT JOIN + +**Example 1: The Timestamp in table1 is Greater Than or Equal to That in table2 with the Closest Timestamp** + +```SQL +SELECT t1.time as time1, t1.device_id as device1, t1.temperature as temperature1, t2.time as time2, t2.device_id as device2, t2.temperature as temperature2 FROM table1 t1 ASOF LEFT JOIN table2 t2 ON t1.time>=t2.time order by time1; +``` + +Query Results + +```SQL ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +| time1|device1|temperature1| time2|device2|temperature2| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0|2024-11-26T13:37:00.000+08:00| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0|2024-11-26T13:37:00.000+08:00| 100| 90.0| +|2024-11-27T16:38:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:39:00.000+08:00| 101| 85.0|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:40:00.000+08:00| 101| 85.0|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:41:00.000+08:00| 101| 85.0|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:42:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:43:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:44:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-28T08:00:00.000+08:00| 100| 85.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-28T09:00:00.000+08:00| 100| null|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-28T10:00:00.000+08:00| 100| 85.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-28T11:00:00.000+08:00| 100| 88.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-29T10:00:00.000+08:00| 101| 85.0|2024-11-29T00:00:00.000+08:00| 101| 85.0| +|2024-11-29T11:00:00.000+08:00| 100| null|2024-11-29T11:00:00.000+08:00| 100| null| +|2024-11-29T18:30:00.000+08:00| 100| 90.0|2024-11-29T11:00:00.000+08:00| 100| null| +|2024-11-30T09:30:00.000+08:00| 101| 90.0|2024-11-30T00:00:00.000+08:00| 101| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-30T00:00:00.000+08:00| 101| 90.0| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +Total line number = 18 +It costs 0.058s +``` + +**Example 2: plant\_id is the Same, and the Timestamp in table1 is Greater Than or Equal to That in table2 with the Closest Timestamp** + + +```SQL +SELECT t1.time as time1, t1.plant_id as plant1, t1.temperature as temperature1, t2.time as time2, t2.plant_id as plant2, t2.temperature as temperature2 FROM table1 t1 ASOF LEFT JOIN table2 t2 ON t1.plant_id=t2.plant_id and t1.time>=t2.time ORDER BY time1; +``` + +Query Results + +```SQL ++-----------------------------+------+------------+-----------------------------+------+------------+ +| time1|plant1|temperature1| time2|plant2|temperature2| ++-----------------------------+------+------------+-----------------------------+------+------------+ +|2024-11-26T13:37:00.000+08:00| 1001| 90.0|2024-11-26T13:37:00.000+08:00| 1001| 90.0| +|2024-11-26T13:38:00.000+08:00| 1001| 90.0|2024-11-26T13:37:00.000+08:00| 1001| 90.0| +|2024-11-27T16:38:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:39:00.000+08:00| 1001| 85.0|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:40:00.000+08:00| 1001| 85.0|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:41:00.000+08:00| 1001| 85.0|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:42:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:43:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:44:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-28T08:00:00.000+08:00| 3001| 85.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-28T09:00:00.000+08:00| 3001| null|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-28T10:00:00.000+08:00| 3001| 85.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-28T11:00:00.000+08:00| 3001| 88.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-29T10:00:00.000+08:00| 3001| 85.0|2024-11-29T00:00:00.000+08:00| 3001| 85.0| +|2024-11-29T11:00:00.000+08:00| 3002| null|2024-11-29T11:00:00.000+08:00| 3002| null| +|2024-11-29T18:30:00.000+08:00| 3002| 90.0|2024-11-29T11:00:00.000+08:00| 3002| null| +|2024-11-30T09:30:00.000+08:00| 3002| 90.0|2024-11-30T00:00:00.000+08:00| 3002| 90.0| +|2024-11-30T14:30:00.000+08:00| 3002| 90.0|2024-11-30T00:00:00.000+08:00| 3002| 90.0| ++-----------------------------+------+------------+-----------------------------+------+------------+ +Total line number = 18 +It costs 0.022s +``` diff --git a/src/UserGuide/latest-Table/SQL-Manual/From-Join-Clause.md b/src/UserGuide/latest-Table/SQL-Manual/From-Join-Clause.md index eb437981c..ceaa9d70e 100644 --- a/src/UserGuide/latest-Table/SQL-Manual/From-Join-Clause.md +++ b/src/UserGuide/latest-Table/SQL-Manual/From-Join-Clause.md @@ -33,7 +33,7 @@ relation joinType : INNER? - | FULL OUTER? + | OUTER? | CROSS? | ASOF? ; @@ -72,8 +72,8 @@ The `JOIN` clause combines two tables based on specific conditions, typically pr In the current version of IoTDB, the following joins are supported: -1. **Inner Join**: Combines rows that meet the join condition, effectively returning the intersection of the two tables. The join condition must be an equality condition on the `time` column. -2. **Full Outer Join**: Returns all records from both tables, inserting `NULL` values for unmatched rows. The join condition can be any equality expression. +1. **Inner Join**: The join condition can be any equality expression. +2. **Outer Join**: The join condition can be any equality expression. 3. **Cross Join**: Represents the Cartesian product of two tables. 4. ​**​ASOF JOIN​​** (AS OF a specific point in time) is a specialized join operation based on temporal or approximate matching conditions, designed for scenarios where timestamps between two datasets are not perfectly aligned. It matches each row from the left table with the closest corresponding row in the right table that meets the specified conditions (typically the nearest preceding or succeeding timestamp). This operation is widely used for time-series data analysis (e.g., sensor data, financial market feeds). @@ -120,7 +120,47 @@ An **outer join** returns rows even when no matching records exist in the other - **RIGHT OUTER JOIN**: Returns all rows from the right table. - **FULL OUTER JOIN**: Returns all rows from both tables. -IoTDB currently supports only `FULL [OUTER] JOIN`. This type returns all records from both tables. If a record in one table has no match in the other, `NULL` values are returned for the unmatched fields. `FULL JOIN` **must use explicit join conditions**. +#### 3.2.1 Left Outer Join + +LEFT [OUTER] JOIN (i.e., left outer join) returns all records from the left table, along with the records from the right table that satisfy the join condition with the left table. For records in the right table that have no matching entries in the left table, NULL values are returned. Since the LEFT JOIN keyword must be specified, left outer join typically uses only the explicit join syntax, where the join condition is specified after ON or USING. + +> Supported in V2.0.5 and later versions + +The SQL syntax is as follows: + +```SQL +-- Explicit join: specify the join condition after the ON keyword or join columns after the USING keyword +SELECT selectExpr [, selectExpr] ... FROM LEFT [OUTER] JOIN joinCriteria [WHERE whereCondition] + +joinCriteria + : ON booleanExpression + | USING '(' identifier (',' identifier)* ')' + ; +``` + +#### 3.2.2 Right Outer Join + +RIGHT [OUTER] JOIN (i.e., right outer join) returns all records from the right table, along with the records from the left table that satisfy the join condition with the right table. For records in the left table that have no matching entries in the right table, NULL values are returned. + +> Supported in V2.0.5 and later versions + +RIGHT JOIN is a "symmetric" operation to LEFT JOIN. In practice, `LEFT JOIN` is more commonly used because we usually care more about the data in the left table in real-world applications. Furthermore, `RIGHT JOIN` can always be converted to `LEFT JOIN` — the query result of `A RIGHT JOIN B ON A.id=B.id` is equivalent to that of `B LEFT JOIN A ON B.id = A.id`. + +The SQL syntax is as follows: + +```SQL +-- Specify the join condition after the ON keyword or join columns after the USING keyword +SELECT selectExpr [, selectExpr] ... FROM RIGHT [OUTER] JOIN joinCriteria [WHERE whereCondition] + +joinCriteria + : ON booleanExpression + | USING '(' identifier (',' identifier)* ')' + ; +``` + +#### 3.2.3 Full Outer Join + +FULL [OUTER] JOIN (i.e., full outer join) returns all records from both tables. If a record in one table has no match in the other, `NULL` values are returned for the unmatched fields. `FULL JOIN` **must use explicit join conditions**. ```sql //Specify the join condition after the ON keyword or specify the join columns after the USING keyword. @@ -137,13 +177,15 @@ A cross join represents the Cartesian product of two tables, returning all possi ### 3.4 ​Asof Join -IoTDB ASOF JOIN is an approximate point join method that allows users to perform matching based on the closest timestamp according to specified rules. ​​The current version only supports ASOF INNER JOIN for Time columns.​​ +IoTDB ASOF JOIN is an approximate point join method that allows users to perform matching based on the closest timestamp according to specified rules. ​​The current version only supports ASOF INNER/LEFT JOIN.​​ + +> ASOF LEFT JOIN supported in V2.0.5 and later versions The SQL syntax is as follows: ```SQL SELECT selectExpr [, selectExpr] ... FROM - ASOF[(tolerance theta)] [INNER] JOIN joinCriteria + ASOF[(tolerance theta)] [INNER|LEFT] JOIN joinCriteria [WHERE whereCondition] WHERE a.time = tolerance(b.time, 1s) @@ -159,7 +201,7 @@ comparisonOperator **​Notes:​​** * ASOF JOIN defaults to ASOF INNER JOIN implementation. -* When using the ON keyword for joining, the join condition must include an inequality join condition for the Time column. Only four operators are supported: `">", ">=", "<", "<="`. The corresponding join matching rules are as follows (where lt represents the left table and rt represents the right table): +* When using the ON keyword for joining, the join condition must include an inequality join condition where both the left and right sides are of TIMESTAMP type (i.e., the primary join condition). Only four operators are supported: `">", ">=", "<", "<="`. The corresponding join matching rules are as follows (where lt represents the left table and rt represents the right table): | Operator | Join Method | | -------------------------- | ---------------------------------------------- | @@ -169,6 +211,51 @@ comparisonOperator | `lt.time < rt.time` | The closest timestamp in the left table that is less than the right table's timestamp. | * `Tolerance parameter​`​: The maximum allowed time difference for searching data in the right table (expressed as a TimeDuration, e.g., 1d for one day). If the Tolerance parameter is not specified, the search time range defaults to ​​infinity​​. ​​Note​​: Currently, this parameter is only supported in ASOF ​​INNER​​ JOIN. +* In addition to the primary join condition, ASOF can also specify equality join conditions for other columns (ID, Attribute, Measurement), which means the query results are grouped by these other columns. The primary join condition must be placed ​**last**​, and it must be connected to other conditions (if any) using "AND". + +### 3.5 Semi Join/Anti-Semi Join + +A semi join is a special join operation whose purpose is to determine whether rows in one table exist in another table. The result set returned by a semi join contains rows from the first table that meet the join condition, but does not include the actual data from the second table. Corresponding to semi join is anti-semi join, which is used to identify rows that have no matches between two tables. The result set returned by an anti-semi join contains rows from the first table that satisfy the join condition, but excludes rows from the second table that match those rows. + +In the IoTDB table model, the `SEMI JOIN` syntax is not provided; instead, IN subqueries or EXISTS subqueries are supported to implement semi joins. Similarly, the `ANTI SEMI JOIN` syntax is not provided, and NOT IN or NOT EXISTS subqueries are supported to implement anti-semi joins. For detailed explanations of subqueries, refer to [Nested Queries](../SQL-Manual/Nested-Queries.md). + +* Examples of semi join syntax are as follows: + +```SQL +-- Implement semi join using IN +SELECT * +FROM table1 +WHERE time IN (SELECT time FROM table2); + +-- Implement semi join using EXISTS +SELECT * +FROM table1 t1 +WHERE EXISTS (SELECT 1 FROM table2 t2 WHERE t1.time = t2.time); + +-- Equivalent to the SEMI JOIN syntax in other databases +SELECT table1.* +FROM table1 SEMI JOIN table2 +ON table1.time=table2.time; +``` + +* Examples of anti-semi join syntax are as follows: + +```SQL +-- Implement anti-semi join using NOT IN +SELECT * +FROM table1 +WHERE time NOT IN (SELECT time FROM table2); + +-- Implement anti-semi join using NOT EXISTS +SELECT * +FROM table1 t1 +WHERE NOT EXISTS (SELECT 1 FROM table2 t2 WHERE t1.time = t2.time); + +-- Equivalent to the ANTI SEMI JOIN syntax in other databases +SELECT table1.* +FROM table1 ANTI JOIN table2 +ON table1.time=table2.time; +``` @@ -192,24 +279,24 @@ Query Results: +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ | time|region|plant_id|device_id|model_id|maintenance|temperature|humidity|status| arrival_time| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ -|2024-11-26T13:37:00.000+08:00| 北京| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:37:34.000+08:00| -|2024-11-26T13:38:00.000+08:00| 北京| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:38:25.000+08:00| -|2024-11-27T16:38:00.000+08:00| 北京| 1001| 101| B| 180| null| 35.1| true|2024-11-27T16:37:01.000+08:00| -|2024-11-27T16:39:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| 35.3| null| null| -|2024-11-27T16:40:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:03.000+08:00| -|2024-11-27T16:41:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:04.000+08:00| -|2024-11-27T16:42:00.000+08:00| 北京| 1001| 101| B| 180| null| 35.2| false| null| -|2024-11-27T16:43:00.000+08:00| 北京| 1001| 101| B| 180| null| null| false| null| -|2024-11-27T16:44:00.000+08:00| 北京| 1001| 101| B| 180| null| null| false|2024-11-27T16:37:08.000+08:00| -|2024-11-28T08:00:00.000+08:00| 上海| 3001| 100| C| 90| 85.0| null| null|2024-11-28T08:00:09.000+08:00| -|2024-11-28T09:00:00.000+08:00| 上海| 3001| 100| C| 90| null| 40.9| true| null| -|2024-11-28T10:00:00.000+08:00| 上海| 3001| 100| C| 90| 85.0| 35.2| null|2024-11-28T10:00:11.000+08:00| -|2024-11-28T11:00:00.000+08:00| 上海| 3001| 100| C| 90| 88.0| 45.1| true|2024-11-28T11:00:12.000+08:00| -|2024-11-29T10:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| null| null|2024-11-29T10:00:13.000+08:00| -|2024-11-29T11:00:00.000+08:00| 上海| 3002| 100| E| 180| null| 45.1| true| null| -|2024-11-29T18:30:00.000+08:00| 上海| 3002| 100| E| 180| 90.0| 35.4| true|2024-11-29T18:30:15.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| -|2024-11-30T14:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00| +|2024-11-26T13:37:00.000+08:00| BJ| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:37:34.000+08:00| +|2024-11-26T13:38:00.000+08:00| BJ| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:38:25.000+08:00| +|2024-11-27T16:38:00.000+08:00| BJ| 1001| 101| B| 180| null| 35.1| true|2024-11-27T16:37:01.000+08:00| +|2024-11-27T16:39:00.000+08:00| BJ| 1001| 101| B| 180| 85.0| 35.3| null| null| +|2024-11-27T16:40:00.000+08:00| BJ| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:03.000+08:00| +|2024-11-27T16:41:00.000+08:00| BJ| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:04.000+08:00| +|2024-11-27T16:42:00.000+08:00| BJ| 1001| 101| B| 180| null| 35.2| false| null| +|2024-11-27T16:43:00.000+08:00| BJ| 1001| 101| B| 180| null| null| false| null| +|2024-11-27T16:44:00.000+08:00| BJ| 1001| 101| B| 180| null| null| false|2024-11-27T16:37:08.000+08:00| +|2024-11-28T08:00:00.000+08:00| SH| 3001| 100| C| 90| 85.0| null| null|2024-11-28T08:00:09.000+08:00| +|2024-11-28T09:00:00.000+08:00| SH| 3001| 100| C| 90| null| 40.9| true| null| +|2024-11-28T10:00:00.000+08:00| SH| 3001| 100| C| 90| 85.0| 35.2| null|2024-11-28T10:00:11.000+08:00| +|2024-11-28T11:00:00.000+08:00| SH| 3001| 100| C| 90| 88.0| 45.1| true|2024-11-28T11:00:12.000+08:00| +|2024-11-29T10:00:00.000+08:00| SH| 3001| 101| D| 360| 85.0| null| null|2024-11-29T10:00:13.000+08:00| +|2024-11-29T11:00:00.000+08:00| SH| 3002| 100| E| 180| null| 45.1| true| null| +|2024-11-29T18:30:00.000+08:00| SH| 3002| 100| E| 180| 90.0| 35.4| true|2024-11-29T18:30:15.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null| +|2024-11-30T14:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ Total line number = 18 It costs 0.085s @@ -227,16 +314,16 @@ Query Results: +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ | time|region|plant_id|device_id|model_id|maintenance|temperature|humidity|status| arrival_time| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ -|2024-11-27T16:38:00.000+08:00| 北京| 1001| 101| B| 180| null| 35.1| true|2024-11-27T16:37:01.000+08:00| -|2024-11-27T16:39:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| 35.3| null| null| -|2024-11-27T16:40:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:03.000+08:00| -|2024-11-27T16:41:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:04.000+08:00| -|2024-11-27T16:42:00.000+08:00| 北京| 1001| 101| B| 180| null| 35.2| false| null| -|2024-11-27T16:43:00.000+08:00| 北京| 1001| 101| B| 180| null| null| false| null| -|2024-11-27T16:44:00.000+08:00| 北京| 1001| 101| B| 180| null| null| false|2024-11-27T16:37:08.000+08:00| -|2024-11-29T10:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| null| null|2024-11-29T10:00:13.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| -|2024-11-30T14:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00| +|2024-11-27T16:38:00.000+08:00| BJ| 1001| 101| B| 180| null| 35.1| true|2024-11-27T16:37:01.000+08:00| +|2024-11-27T16:39:00.000+08:00| BJ| 1001| 101| B| 180| 85.0| 35.3| null| null| +|2024-11-27T16:40:00.000+08:00| BJ| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:03.000+08:00| +|2024-11-27T16:41:00.000+08:00| BJ| 1001| 101| B| 180| 85.0| null| null|2024-11-27T16:37:04.000+08:00| +|2024-11-27T16:42:00.000+08:00| BJ| 1001| 101| B| 180| null| 35.2| false| null| +|2024-11-27T16:43:00.000+08:00| BJ| 1001| 101| B| 180| null| null| false| null| +|2024-11-27T16:44:00.000+08:00| BJ| 1001| 101| B| 180| null| null| false|2024-11-27T16:37:08.000+08:00| +|2024-11-29T10:00:00.000+08:00| SH| 3001| 101| D| 360| 85.0| null| null|2024-11-29T10:00:13.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null| +|2024-11-30T14:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ Total line number = 10 It costs 0.061s @@ -355,8 +442,273 @@ Total line number = 3 It costs 0.082s ``` +**Example 4: Equality Join on Non-time Columns** + +```SQL +SELECT + t1.time, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 JOIN table2 t2 +ON t1.device_id = t2.device_id +ORDER BY t1.time +LIMIT 10 +``` + +Query Results: + +```SQL ++-----------------------------+-------+------------+-------+------------+ +| time|device1|temperature1|device2|temperature2| ++-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| null| +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 85.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| 100| null| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| 100| 85.0| +|2024-11-27T16:38:00.000+08:00| 101| null| 101| 90.0| +|2024-11-27T16:38:00.000+08:00| 101| null| 101| 85.0| +|2024-11-27T16:38:00.000+08:00| 101| null| 101| 85.0| +|2024-11-27T16:39:00.000+08:00| 101| 85.0| 101| 90.0| ++-----------------------------+-------+------------+-------+------------+ +Total line number = 10 +It costs 0.030s +``` + + + #### 4.2.2 Outer Join +1. LEFT JOIN + +**Example 1: Explicit Join** + +```SQL +SELECT + t1.time as time1, t2.time as time2, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 LEFT JOIN table2 t2 +ON t1.time = t2.time +``` + +Query Results: + +```SQL ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +| time1| time2|device1|temperature1|device2|temperature2| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| null| 100| 90.0| null| null| +|2024-11-27T16:38:00.000+08:00| null| 101| null| null| null| +|2024-11-27T16:39:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-27T16:40:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-27T16:41:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-27T16:42:00.000+08:00| null| 101| null| null| null| +|2024-11-27T16:43:00.000+08:00| null| 101| null| null| null| +|2024-11-27T16:44:00.000+08:00| null| 101| null| null| null| +|2024-11-28T08:00:00.000+08:00|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +|2024-11-28T09:00:00.000+08:00| null| 100| null| null| null| +|2024-11-28T10:00:00.000+08:00| null| 100| 85.0| null| null| +|2024-11-28T11:00:00.000+08:00| null| 100| 88.0| null| null| +|2024-11-29T10:00:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-29T11:00:00.000+08:00|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +|2024-11-29T18:30:00.000+08:00| null| 100| 90.0| null| null| +|2024-11-30T09:30:00.000+08:00| null| 101| 90.0| null| null| +|2024-11-30T14:30:00.000+08:00| null| 101| 90.0| null| null| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +Total line number = 18 +It costs 0.031s +``` + +**Example 2: Explicit Join** + +```SQL +SELECT + time, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 LEFT JOIN table2 t2 +USING(time) +``` + +Query Results: + +```SQL ++-----------------------------+-------+------------+-------+------------+ +| time|device1|temperature1|device2|temperature2| ++-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| null| null| +|2024-11-27T16:38:00.000+08:00| 101| null| null| null| +|2024-11-27T16:39:00.000+08:00| 101| 85.0| null| null| +|2024-11-27T16:40:00.000+08:00| 101| 85.0| null| null| +|2024-11-27T16:41:00.000+08:00| 101| 85.0| null| null| +|2024-11-27T16:42:00.000+08:00| 101| null| null| null| +|2024-11-27T16:43:00.000+08:00| 101| null| null| null| +|2024-11-27T16:44:00.000+08:00| 101| null| null| null| +|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +|2024-11-28T09:00:00.000+08:00| 100| null| null| null| +|2024-11-28T10:00:00.000+08:00| 100| 85.0| null| null| +|2024-11-28T11:00:00.000+08:00| 100| 88.0| null| null| +|2024-11-29T10:00:00.000+08:00| 101| 85.0| null| null| +|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +|2024-11-29T18:30:00.000+08:00| 100| 90.0| null| null| +|2024-11-30T09:30:00.000+08:00| 101| 90.0| null| null| +|2024-11-30T14:30:00.000+08:00| 101| 90.0| null| null| ++-----------------------------+-------+------------+-------+------------+ +Total line number = 18 +It costs 0.031s +``` + +**Example 3: Join Condition on Non-time Column** + +```SQL +SELECT + region, + t1.time as time1, + t1.temperature as temperature1, + t2.time as time2, + t2.temperature as temperature2 +FROM + table1 t1 LEFT JOIN table2 t2 +USING(region) +LIMIT 10 +``` + +Query Results: + +```SQL ++------+-----------------------------+------------+-----------------------------+------------+ +|region| time1|temperature1| time2|temperature2| ++------+-----------------------------+------------+-----------------------------+------------+ +|Shanghai|2024-11-29T11:00:00.000+08:00| null|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-29T11:00:00.000+08:00| null|2024-11-28T08:00:00.000+08:00| 85.0| +|Shanghai|2024-11-29T11:00:00.000+08:00| null|2024-11-30T00:00:00.000+08:00| 90.0| +|Shanghai|2024-11-29T11:00:00.000+08:00| null|2024-11-29T00:00:00.000+08:00| 85.0| +|Shanghai|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-28T08:00:00.000+08:00| 85.0| +|Shanghai|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-30T00:00:00.000+08:00| 90.0| +|Shanghai|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-29T00:00:00.000+08:00| 85.0| +|Shanghai|2024-11-29T18:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-29T18:30:00.000+08:00| 90.0|2024-11-28T08:00:00.000+08:00| 85.0| ++------+-----------------------------+------------+-----------------------------+------------+ +Total line number = 10 +It costs 0.038s +``` + +2. RIGHT JOIN + +**Example 1: Explicit Join** + +```SQL +SELECT + t1.time as time1, t2.time as time2, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 RIGHT JOIN table2 t2 +ON t1.time = t2.time +``` + +Query Results: + +```SQL ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +| time1| time2|device1|temperature1|device2|temperature2| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +| null|2024-11-27T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-28T08:00:00.000+08:00|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +| null|2024-11-29T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-29T11:00:00.000+08:00|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +| null|2024-11-30T00:00:00.000+08:00| null| null| 101| 90.0| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +Total line number = 6 +It costs 0.030s +``` + +**Example 2: Explicit Join** + +```SQL +SELECT + time, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 RIGHT JOIN table2 t2 +USING(time) +``` + +Query Results: + +```SQL ++-----------------------------+-------+------------+-------+------------+ +| time|device1|temperature1|device2|temperature2| ++-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-27T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +|2024-11-29T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +|2024-11-30T00:00:00.000+08:00| null| null| 101| 90.0| ++-----------------------------+-------+------------+-------+------------+ +Total line number = 6 +It costs 0.053s +``` + +**Example 3: Join Condition on Non-time Column** + +```SQL +SELECT + region, + t1.time as time1, + t1.temperature as temperature1, + t2.time as time2, + t2.temperature as temperature2 +FROM + table1 t1 RIGHT JOIN table2 t2 +USING(region) +LIMIT 10 +``` + +Query Results: + +```SQL ++------+-----------------------------+------------+-----------------------------+------------+ +|region| time1|temperature1| time2|temperature2| ++------+-----------------------------+------------+-----------------------------+------------+ +|Shanghai|2024-11-29T11:00:00.000+08:00| null|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-29T18:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-28T08:00:00.000+08:00| 85.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-30T14:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-29T10:00:00.000+08:00| 85.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-28T09:00:00.000+08:00| null|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-28T10:00:00.000+08:00| 85.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-28T11:00:00.000+08:00| 88.0|2024-11-29T11:00:00.000+08:00| null| +|Shanghai|2024-11-29T11:00:00.000+08:00| null|2024-11-28T08:00:00.000+08:00| 85.0| ++------+-----------------------------+------------+-----------------------------+------------+ +Total line number = 10 +It costs 0.029s +``` + +3. FULL JOIN + **Example 1: Full Outer Join using `ON`** This query retrieves all records from `table1` and `table2`, including unmatched rows with `NULL` values. @@ -503,14 +855,14 @@ Query Results: +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ | time|region|plant_id|device_id|model_id|maintenance|temperature|humidity|status| arrival_time| time|region|plant_id|device_id|model_id|maintenance|temperature|humidity|status| arrival_time| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-27T00:00:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| 35.1| true|2024-11-27T16:37:01.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T11:00:00.000+08:00| 上海| 3002| 100| E| 180| null| 45.1| true| null| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-28T08:00:00.000+08:00| 上海| 3001| 100| C| 90| 85.0| 35.2| false|2024-11-28T08:00:09.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-26T13:37:00.000+08:00| 北京| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:37:34.000+08:00| -|2024-11-30T14:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| -|2024-11-30T14:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-27T00:00:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| 35.1| true|2024-11-27T16:37:01.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T11:00:00.000+08:00| 上海| 3002| 100| E| 180| null| 45.1| true| null| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-28T08:00:00.000+08:00| 上海| 3001| 100| C| 90| 85.0| 35.2| false|2024-11-28T08:00:09.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-26T13:37:00.000+08:00| 北京| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:37:34.000+08:00| +|2024-11-30T14:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| +|2024-11-30T14:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ Total line number = 8 It costs 0.282s @@ -528,14 +880,14 @@ Query Results: +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ | time|region|plant_id|device_id|model_id|maintenance|temperature|humidity|status| arrival_time| time|region|plant_id|device_id|model_id|maintenance|temperature|humidity|status| arrival_time| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-27T00:00:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| 35.1| true|2024-11-27T16:37:01.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T11:00:00.000+08:00| 上海| 3002| 100| E| 180| null| 45.1| true| null| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-28T08:00:00.000+08:00| 上海| 3001| 100| C| 90| 85.0| 35.2| false|2024-11-28T08:00:09.000+08:00| -|2024-11-30T09:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-26T13:37:00.000+08:00| 北京| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:37:34.000+08:00| -|2024-11-30T14:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| -|2024-11-30T14:30:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-27T00:00:00.000+08:00| 北京| 1001| 101| B| 180| 85.0| 35.1| true|2024-11-27T16:37:01.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-29T11:00:00.000+08:00| 上海| 3002| 100| E| 180| null| 45.1| true| null| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-28T08:00:00.000+08:00| 上海| 3001| 100| C| 90| 85.0| 35.2| false|2024-11-28T08:00:09.000+08:00| +|2024-11-30T09:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 35.2| true| null|2024-11-26T13:37:00.000+08:00| 北京| 1001| 100| A| 180| 90.0| 35.1| true|2024-11-26T13:37:34.000+08:00| +|2024-11-30T14:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-30T00:00:00.000+08:00| 上海| 3002| 101| F| 360| 90.0| 35.2| true| null| +|2024-11-30T14:30:00.000+08:00| SH| 3002| 101| F| 360| 90.0| 34.8| true|2024-11-30T14:30:17.000+08:00|2024-11-29T00:00:00.000+08:00| 上海| 3001| 101| D| 360| 85.0| 35.1| null|2024-11-29T10:00:13.000+08:00| +-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+-----------------------------+------+--------+---------+--------+-----------+-----------+--------+------+-----------------------------+ Total line number = 8 It costs 0.047s @@ -543,6 +895,8 @@ It costs 0.047s #### 4.2.4 Asof join +1. ASOF INNER JOIN + ​​Example 1​​: Without specifying the tolerance parameter, where the timestamp in table1 is greater than or equal to and closest to the timestamp in table2. ```SQL @@ -593,3 +947,121 @@ Query Results: |2024-11-26T13:37:00.000+08:00| 100| 90.0|2024-11-26T13:37:00.000+08:00| 100| 90.0| +-----------------------------+-------+------------+-----------------------------+-------+------------+ ``` + +**Example 3: Tolerance Parameter Specified, plant\_id is the Same, and the Timestamp in table1 is Greater Than or Equal to That in table2 with the Closest Timestamp** + +```SQL +SELECT t1.time as time1, t1.plant_id as plant1, t1.temperature as temperature1, t2.time as time2, t2.plant_id as plant2, t2.temperature as temperature2 FROM table1 t1 ASOF(tolerance 2s) JOIN table2 t2 ON t1.plant_id=t2.plant_id and t1.time>=t2.time; +``` + +Query Results + +```SQL ++-----------------------------+------+------------+-----------------------------+------+------------+ +| time1|plant1|temperature1| time2|plant2|temperature2| ++-----------------------------+------+------------+-----------------------------+------+------------+ +|2024-11-26T13:37:00.000+08:00| 1001| 90.0|2024-11-26T13:37:00.000+08:00| 1001| 90.0| +|2024-11-28T08:00:00.000+08:00| 3001| 85.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-29T11:00:00.000+08:00| 3002| null|2024-11-29T11:00:00.000+08:00| 3002| null| ++-----------------------------+------+------------+-----------------------------+------+------------+ +Total line number = 3 +It costs 0.046s +``` + +**Example 4: Asof Join Between a Time Period Today and the Corresponding Time Period Last Week** + +```SQL +SELECT * FROM (SELECT time, device_id AS device1, temperature AS temperature1 FROM table1 ) AS t1 ASOF JOIN (SELECT time, device_id AS device2, temperature AS temperature2 FROM table1) AS t2 ON t1.time>date_bin(1w, t2.time) limit 10 +``` + +Query Results: + +```SQL ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +| time|device1|temperature1| time|device2|temperature2| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-29T11:00:00.000+08:00| 100| null| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-30T09:30:00.000+08:00| 101| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-29T18:30:00.000+08:00| 100| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-30T14:30:00.000+08:00| 101| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-29T10:00:00.000+08:00| 101| 85.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T09:00:00.000+08:00| 100| null| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T10:00:00.000+08:00| 100| 85.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T11:00:00.000+08:00| 100| 88.0| +|2024-11-30T09:30:00.000+08:00| 101| 90.0|2024-11-29T11:00:00.000+08:00| 100| null| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +``` + +2. ASOF LEFT JOIN + +**Example 1: The Timestamp in table1 is Greater Than or Equal to That in table2 with the Closest Timestamp** + +```SQL +SELECT t1.time as time1, t1.device_id as device1, t1.temperature as temperature1, t2.time as time2, t2.device_id as device2, t2.temperature as temperature2 FROM table1 t1 ASOF LEFT JOIN table2 t2 ON t1.time>=t2.time order by time1; +``` + +Query Results + +```SQL ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +| time1|device1|temperature1| time2|device2|temperature2| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0|2024-11-26T13:37:00.000+08:00| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0|2024-11-26T13:37:00.000+08:00| 100| 90.0| +|2024-11-27T16:38:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:39:00.000+08:00| 101| 85.0|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:40:00.000+08:00| 101| 85.0|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:41:00.000+08:00| 101| 85.0|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:42:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:43:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:44:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-28T08:00:00.000+08:00| 100| 85.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-28T09:00:00.000+08:00| 100| null|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-28T10:00:00.000+08:00| 100| 85.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-28T11:00:00.000+08:00| 100| 88.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-29T10:00:00.000+08:00| 101| 85.0|2024-11-29T00:00:00.000+08:00| 101| 85.0| +|2024-11-29T11:00:00.000+08:00| 100| null|2024-11-29T11:00:00.000+08:00| 100| null| +|2024-11-29T18:30:00.000+08:00| 100| 90.0|2024-11-29T11:00:00.000+08:00| 100| null| +|2024-11-30T09:30:00.000+08:00| 101| 90.0|2024-11-30T00:00:00.000+08:00| 101| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-30T00:00:00.000+08:00| 101| 90.0| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +Total line number = 18 +It costs 0.058s +``` + +**Example 2: plant\_id is the Same, and the Timestamp in table1 is Greater Than or Equal to That in table2 with the Closest Timestamp** + + +```SQL +SELECT t1.time as time1, t1.plant_id as plant1, t1.temperature as temperature1, t2.time as time2, t2.plant_id as plant2, t2.temperature as temperature2 FROM table1 t1 ASOF LEFT JOIN table2 t2 ON t1.plant_id=t2.plant_id and t1.time>=t2.time ORDER BY time1; +``` + +Query Results + +```SQL ++-----------------------------+------+------------+-----------------------------+------+------------+ +| time1|plant1|temperature1| time2|plant2|temperature2| ++-----------------------------+------+------------+-----------------------------+------+------------+ +|2024-11-26T13:37:00.000+08:00| 1001| 90.0|2024-11-26T13:37:00.000+08:00| 1001| 90.0| +|2024-11-26T13:38:00.000+08:00| 1001| 90.0|2024-11-26T13:37:00.000+08:00| 1001| 90.0| +|2024-11-27T16:38:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:39:00.000+08:00| 1001| 85.0|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:40:00.000+08:00| 1001| 85.0|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:41:00.000+08:00| 1001| 85.0|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:42:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:43:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:44:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-28T08:00:00.000+08:00| 3001| 85.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-28T09:00:00.000+08:00| 3001| null|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-28T10:00:00.000+08:00| 3001| 85.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-28T11:00:00.000+08:00| 3001| 88.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-29T10:00:00.000+08:00| 3001| 85.0|2024-11-29T00:00:00.000+08:00| 3001| 85.0| +|2024-11-29T11:00:00.000+08:00| 3002| null|2024-11-29T11:00:00.000+08:00| 3002| null| +|2024-11-29T18:30:00.000+08:00| 3002| 90.0|2024-11-29T11:00:00.000+08:00| 3002| null| +|2024-11-30T09:30:00.000+08:00| 3002| 90.0|2024-11-30T00:00:00.000+08:00| 3002| 90.0| +|2024-11-30T14:30:00.000+08:00| 3002| 90.0|2024-11-30T00:00:00.000+08:00| 3002| 90.0| ++-----------------------------+------+------------+-----------------------------+------+------------+ +Total line number = 18 +It costs 0.022s +``` diff --git a/src/zh/UserGuide/Master/Table/SQL-Manual/From-Join-Clause.md b/src/zh/UserGuide/Master/Table/SQL-Manual/From-Join-Clause.md index 0ad97598f..4daa47dac 100644 --- a/src/zh/UserGuide/Master/Table/SQL-Manual/From-Join-Clause.md +++ b/src/zh/UserGuide/Master/Table/SQL-Manual/From-Join-Clause.md @@ -33,7 +33,7 @@ relation joinType : INNER? - | FULL OUTER? + | OUTER? | CROSS? | ASOF? ; @@ -72,8 +72,8 @@ JOIN 用于将两个表基于某些条件连接起来,通常,连接条件是 在当前版本的 IoTDB 中,支持以下连接方式: -* 内连接(Inner Join),连接条件只能是时间列的等值连接。 -* 全外连接(Full Outer Join),连接条件可以是任意等值表达式。 +* 内连接(Inner Join),连接条件可以是任意等值表达式。 +- 外连接(Outer Join),连接条件可以是任意等值表达式。 * 交叉连接(Cross Join) * ASOF JOIN(AS OF a specific point in time,特定时间点),是一种基于时间或近似匹配条件的特殊连接操作,适用于两个数据集的时间戳不完全对齐的场景。它能够为左表的每一行找到右表中时间最接近且满足条件的对应行,常用于处理时间序列数据(如传感器数据、金融行情等)。 @@ -120,7 +120,47 @@ SELECT selectExpr [, selectExpr] ... FROM [, ] ... [WHE - RIGHT(右侧表的所有行至少出现一次) - FULL(两个表的所有行至少出现一次) -在当前版本的 IoTDB 中,只支持 FULL [OUTER] JOIN,即全外连接,返回左表和右表连接后的所有记录。如果某个表中的记录没有与另一个表中的记录匹配,则会返回 NULL 值。__FULL JOIN 只能使用显式连接方式。__ +#### 3.2.1 左外连接 + +LEFT [OUTER] JOIN,即左外连接,返回左表中的所有记录,以及右表中与左表满足连接条件的记录。对于右表中没有与左表匹配的记录返回NULL值。因为需要指定LEFT JOIN关键字,所以左外连接一般只使用显示连接的语法,即在ON或USING后指定连接条件。 + +> V 2.0.5 及以后版本支持 + +SQL语法如下所示: + +```SQL +// 显示连接, 在ON关键字后指定连接条件或在Using关键字后指定连接列 +SELECT selectExpr [, selectExpr] ... FROM LEFT [OUTER] JOIN joinCriteria [WHERE whereCondition] + +joinCriteria + : ON booleanExpression + | USING '(' identifier (',' identifier)* ')' + ; +``` + +#### 3.2.2 右外连接 + +RIGHT [OUTER] JOIN, 即右外连接,返回右表中的所有记录,以及左表中与右表满足连接条件的记录。对于左表中没有与右表匹配的记录返回NULL值。 + +> V 2.0.5 及以后版本支持 + +RIGHT JOIN与LEFT JOIN是“对称”的操作,通常情况下,使用 `LEFT JOIN` 比较常见,因为在实际应用中通常更关心左表的数据。而且`RIGHT JOIN` 总可以转换为`LEFT JOIN` ,即`A RIGHT JOIN B ON A.id=B.id` 的查询结果与 `B LEFT JOIN A on B.id = A.id`是等价的。 + +SQL语法如下所示: + +```SQL +// 在ON关键字后指定连接条件或在Using关键字后指定连接列 +SELECT selectExpr [, selectExpr] ... FROM RIGHT [OUTER] JOIN joinCriteria [WHERE whereCondition] + +joinCriteria + : ON booleanExpression + | USING '(' identifier (',' identifier)* ')' + ; +``` + +#### 3.2.3 全外连接 + +FULL [OUTER] JOIN,即全外连接,返回左表和右表连接后的所有记录。如果某个表中的记录没有与另一个表中的记录匹配,则会返回 NULL 值。__FULL JOIN 只能使用显式连接方式。__ SQL语法如下所示: @@ -139,13 +179,14 @@ joinCriteria ### 3.4 非精确点连接(​ASOF JOIN​) -IoTDB ASOF JOIN 即非精确点连接方式,允许用户按照指定的规则以时间戳最接近的方式进行匹配。**目前版本只支持针对 Time 列的 ASOF INNER JOIN。** +IoTDB ASOF JOIN 即非精确点连接方式,允许用户按照指定的规则以时间戳最接近的方式进行匹配。**目前版本只支持 ASOF INNER/LEFT JOIN。** +> ASOF LEFT JOIN 方式 V2.0.5 及以后版本支持 SQL语法如下所示: ```SQL SELECT selectExpr [, selectExpr] ... FROM - ASOF[(tolerance theta)] [INNER] JOIN joinCriteria + ASOF[(tolerance theta)] [INNER|LEFT] JOIN joinCriteria [WHERE whereCondition] WHERE a.time = tolerance(b.time, 1s) @@ -161,7 +202,7 @@ comparisonOperator **说明:** * ASOF JOIN 默认使用 ASOF INNER JOIN 实现 -* 当使用 ON 关键字进行连接时,连接条件里必须包含针对 Time 列的不等式连接条件,不等式仅支持 `">", ">=", "<", "<="` 四种操作符,其代表的连接匹配规则如下:其中 lt 表示 left table, rt 表示 right table +* 当使用 ON 关键字进行连接时,连接条件里必须包含左右均为 TIMESTAMP 类型的不等式连接条件(即主连接条件),不等式仅支持 `">", ">=", "<", "<="` 四种操作符,其代表的连接匹配规则如下:其中 lt 表示 left table, rt 表示 right table | 运算符 | 连接方式 | | -------------------------- | ---------------------------------------------- | @@ -171,8 +212,51 @@ comparisonOperator | `lt.time < rt.time` | 左表中时间戳小于右表时间戳且时间戳最接近 | * Tolerance 参数:容差,表示右表数据查找允许的最大时间差。(用 TimeDuration 表示,如 1d 表示1天)。如果不指定 Tolerance 参数,则表示查找时间范围为​**正无穷**​。注意:目前仅 ASOF **INNER** JOIN 中支持该参数 +* ASOF 除了主连接条件外,还可以指定针对其它列(ID、Attribute、Measurement)的等值连接条件,表示查询结果按照其它列进行分组。主连接条件必须**放在最后**,并且主连接条件与其他条件(如果有的话)之间必须使用"AND"进行连接。 + +### 3.5 半连接/反连接(SEMI JOIN/ANTI-SEMI JOIN) +半连接是一种特殊的连接操作,其目的是确定一个表中的行是否存在于另一个表中。半连接返回的结果集包含符合连接条件的第一个表的行,而不包含第二个表的实际数据。与半连接对应的是反连接,反连接目的是确定两个表之间没有匹配的行。反连接返回的结果集包含满足连接条件的第一个表中的行,但不包含第二个表中与之匹配的行。 +在IoTDB表模型中,不提供\`SEMI JOIN\`语法,支持使用 IN 子查询或 EXISTS 子查询来实现半连接;同样,也不提供\`ANTI SEMI JOIN\`语法,支持使用 NOT IN 或 NOT EXISTS 子查询来实现反连接。关于子查询详细说明可参考[嵌套查询](../SQL-Manual/Nested-Queries.md) + +* 半连接语法示例如下: + +```SQL +// 使用IN实现半连接 +SELECT * +FROM table1 +WHERE time IN (SELECT time FROM table2); + +// 使用EXISTS实现半连接 +SELECT * +FROM table1 t1 +WHERE EXISTS (SELECT 1 FROM table2 t2 WHERE t1.time = t2.time); + +// 等同于其他数据库的SEMI JOIN语法 +SELECT table1.* +FROM table1 SEMI JOIN table2 +on table1.time=table2.time; +``` + +* 反连接语法示例如下: + +```SQL +// 使用NOT IN实现反连接 +SELECT * +FROM table1 +WHERE time NOT IN (SELECT time FROM table2); + +// 使用NOT EXISTS实现反连接 +SELECT * +FROM table1 t1 +WHERE NOT EXISTS (SELECT 1 FROM table2 t2 WHERE t1.time = t2.time); + +// 等同于其他数据库的ANTI SEMI JOIN语法 +SELECT table1.* +FROM table1 ANTI JOIN table2 +on table1.time=table2.time; +``` ## 4. 示例数据 @@ -351,8 +435,272 @@ Total line number = 3 It costs 0.082s ``` +示例4:非 time 列等值连接 + +```SQL +SELECT + t1.time, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 JOIN table2 t2 +ON t1.device_id = t2.device_id +ORDER BY t1.time +LIMIT 10 +``` + +查询结果: + +```SQL ++-----------------------------+-------+------------+-------+------------+ +| time|device1|temperature1|device2|temperature2| ++-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| null| +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 85.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| 100| null| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| 100| 85.0| +|2024-11-27T16:38:00.000+08:00| 101| null| 101| 90.0| +|2024-11-27T16:38:00.000+08:00| 101| null| 101| 85.0| +|2024-11-27T16:38:00.000+08:00| 101| null| 101| 85.0| +|2024-11-27T16:39:00.000+08:00| 101| 85.0| 101| 90.0| ++-----------------------------+-------+------------+-------+------------+ +Total line number = 10 +It costs 0.030s +``` + + #### 4.2.2 Outer Join +1. LEFT JOIN + +示例 1:显式连接 + +```SQL +SELECT + t1.time as time1, t2.time as time2, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 LEFT JOIN table2 t2 +ON t1.time = t2.time +``` + +查询结果: + +```SQL ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +| time1| time2|device1|temperature1|device2|temperature2| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| null| 100| 90.0| null| null| +|2024-11-27T16:38:00.000+08:00| null| 101| null| null| null| +|2024-11-27T16:39:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-27T16:40:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-27T16:41:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-27T16:42:00.000+08:00| null| 101| null| null| null| +|2024-11-27T16:43:00.000+08:00| null| 101| null| null| null| +|2024-11-27T16:44:00.000+08:00| null| 101| null| null| null| +|2024-11-28T08:00:00.000+08:00|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +|2024-11-28T09:00:00.000+08:00| null| 100| null| null| null| +|2024-11-28T10:00:00.000+08:00| null| 100| 85.0| null| null| +|2024-11-28T11:00:00.000+08:00| null| 100| 88.0| null| null| +|2024-11-29T10:00:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-29T11:00:00.000+08:00|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +|2024-11-29T18:30:00.000+08:00| null| 100| 90.0| null| null| +|2024-11-30T09:30:00.000+08:00| null| 101| 90.0| null| null| +|2024-11-30T14:30:00.000+08:00| null| 101| 90.0| null| null| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +Total line number = 18 +It costs 0.031s +``` + +示例 2:显式连接 + +```SQL +SELECT + time, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 LEFT JOIN table2 t2 +USING(time) +``` + +查询结果: + +```SQL ++-----------------------------+-------+------------+-------+------------+ +| time|device1|temperature1|device2|temperature2| ++-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| null| null| +|2024-11-27T16:38:00.000+08:00| 101| null| null| null| +|2024-11-27T16:39:00.000+08:00| 101| 85.0| null| null| +|2024-11-27T16:40:00.000+08:00| 101| 85.0| null| null| +|2024-11-27T16:41:00.000+08:00| 101| 85.0| null| null| +|2024-11-27T16:42:00.000+08:00| 101| null| null| null| +|2024-11-27T16:43:00.000+08:00| 101| null| null| null| +|2024-11-27T16:44:00.000+08:00| 101| null| null| null| +|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +|2024-11-28T09:00:00.000+08:00| 100| null| null| null| +|2024-11-28T10:00:00.000+08:00| 100| 85.0| null| null| +|2024-11-28T11:00:00.000+08:00| 100| 88.0| null| null| +|2024-11-29T10:00:00.000+08:00| 101| 85.0| null| null| +|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +|2024-11-29T18:30:00.000+08:00| 100| 90.0| null| null| +|2024-11-30T09:30:00.000+08:00| 101| 90.0| null| null| +|2024-11-30T14:30:00.000+08:00| 101| 90.0| null| null| ++-----------------------------+-------+------------+-------+------------+ +Total line number = 18 +It costs 0.031s +``` + +示例3:连接条件为非time列 + +```SQL +SELECT + region, + t1.time as time1, + t1.temperature as temperature1, + t2.time as time2, + t2.temperature as temperature2 +FROM + table1 t1 LEFT JOIN table2 t2 +USING(region) +LIMIT 10 +``` + +查询结果: + +```SQL ++------+-----------------------------+------------+-----------------------------+------------+ +|region| time1|temperature1| time2|temperature2| ++------+-----------------------------+------------+-----------------------------+------------+ +| 上海|2024-11-29T11:00:00.000+08:00| null|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-29T11:00:00.000+08:00| null|2024-11-28T08:00:00.000+08:00| 85.0| +| 上海|2024-11-29T11:00:00.000+08:00| null|2024-11-30T00:00:00.000+08:00| 90.0| +| 上海|2024-11-29T11:00:00.000+08:00| null|2024-11-29T00:00:00.000+08:00| 85.0| +| 上海|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-28T08:00:00.000+08:00| 85.0| +| 上海|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-30T00:00:00.000+08:00| 90.0| +| 上海|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-29T00:00:00.000+08:00| 85.0| +| 上海|2024-11-29T18:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-29T18:30:00.000+08:00| 90.0|2024-11-28T08:00:00.000+08:00| 85.0| ++------+-----------------------------+------------+-----------------------------+------------+ +Total line number = 10 +It costs 0.038s +``` + +2. RIGHT JOIN + +示例 1:显式连接 + +```SQL +SELECT + t1.time as time1, t2.time as time2, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 RIGHT JOIN table2 t2 +ON t1.time = t2.time +``` + +查询结果: + +```SQL ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +| time1| time2|device1|temperature1|device2|temperature2| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +| null|2024-11-27T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-28T08:00:00.000+08:00|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +| null|2024-11-29T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-29T11:00:00.000+08:00|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +| null|2024-11-30T00:00:00.000+08:00| null| null| 101| 90.0| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +Total line number = 6 +It costs 0.030s +``` + +示例 2:显式连接 + +```SQL +SELECT + time, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 RIGHT JOIN table2 t2 +USING(time) +``` + +查询结果: + +```SQL ++-----------------------------+-------+------------+-------+------------+ +| time|device1|temperature1|device2|temperature2| ++-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-27T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +|2024-11-29T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +|2024-11-30T00:00:00.000+08:00| null| null| 101| 90.0| ++-----------------------------+-------+------------+-------+------------+ +Total line number = 6 +It costs 0.053s +``` + +示例3:连接条件为非time列 + +```SQL +SELECT + region, + t1.time as time1, + t1.temperature as temperature1, + t2.time as time2, + t2.temperature as temperature2 +FROM + table1 t1 RIGHT JOIN table2 t2 +USING(region) +LIMIT 10 +``` + +查询结果: + +```SQL ++------+-----------------------------+------------+-----------------------------+------------+ +|region| time1|temperature1| time2|temperature2| ++------+-----------------------------+------------+-----------------------------+------------+ +| 上海|2024-11-29T11:00:00.000+08:00| null|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-29T18:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-28T08:00:00.000+08:00| 85.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-30T14:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-29T10:00:00.000+08:00| 85.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-28T09:00:00.000+08:00| null|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-28T10:00:00.000+08:00| 85.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-28T11:00:00.000+08:00| 88.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-29T11:00:00.000+08:00| null|2024-11-28T08:00:00.000+08:00| 85.0| ++------+-----------------------------+------------+-----------------------------+------------+ +Total line number = 10 +It costs 0.029s +``` + +3. FULL JOIN + 示例 1:显式连接 ```sql @@ -535,6 +883,8 @@ It costs 0.047s #### 4.2.4 Asof join +1. ASOF INNER JOIN + 示例1:不指定 Tolerance 参数,且 table1 中时间戳大于等于 table2 时间戳且时间戳最接近 ```SQL @@ -585,3 +935,119 @@ SELECT t1.time as time1, t1.device_id as device1, t1.temperature as temperature1 |2024-11-26T13:37:00.000+08:00| 100| 90.0|2024-11-26T13:37:00.000+08:00| 100| 90.0| +-----------------------------+-------+------------+-----------------------------+-------+------------+ ``` +示例3:指定 Tolerance 参数,plant\_id 相同且 table1 中时间戳大于等于 table2 时间戳且时间戳最接近 + +```SQL +SELECT t1.time as time1, t1.plant_id as plant1, t1.temperature as temperature1, t2.time as time2, t2.plant_id as plant2, t2.temperature as temperature2 FROM table1 t1 ASOF(tolerance 2s) JOIN table2 t2 ON t1.plant_id=t2.plant_id and t1.time>=t2.time; +``` + +查询结果 + +```SQL ++-----------------------------+------+------------+-----------------------------+------+------------+ +| time1|plant1|temperature1| time2|plant2|temperature2| ++-----------------------------+------+------------+-----------------------------+------+------------+ +|2024-11-26T13:37:00.000+08:00| 1001| 90.0|2024-11-26T13:37:00.000+08:00| 1001| 90.0| +|2024-11-28T08:00:00.000+08:00| 3001| 85.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-29T11:00:00.000+08:00| 3002| null|2024-11-29T11:00:00.000+08:00| 3002| null| ++-----------------------------+------+------------+-----------------------------+------+------------+ +Total line number = 3 +It costs 0.046s +``` + +示例4: 今天某时间段与上周某时间段的 asof join + +```SQL +SELECT * FROM (SELECT time, device_id AS device1, temperature AS temperature1 FROM table1 ) AS t1 ASOF JOIN (SELECT time, device_id AS device2, temperature AS temperature2 FROM table1) AS t2 ON t1.time>date_bin(1w, t2.time) limit 10 +``` + +查询结果: + +```SQL ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +| time|device1|temperature1| time|device2|temperature2| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-29T11:00:00.000+08:00| 100| null| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-30T09:30:00.000+08:00| 101| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-29T18:30:00.000+08:00| 100| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-30T14:30:00.000+08:00| 101| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-29T10:00:00.000+08:00| 101| 85.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T09:00:00.000+08:00| 100| null| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T10:00:00.000+08:00| 100| 85.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T11:00:00.000+08:00| 100| 88.0| +|2024-11-30T09:30:00.000+08:00| 101| 90.0|2024-11-29T11:00:00.000+08:00| 100| null| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +``` + +2. ASOF LEFT JOIN + +示例1:table1 中时间戳大于等于 table2 时间戳且时间戳最接近 + +```SQL +SELECT t1.time as time1, t1.device_id as device1, t1.temperature as temperature1, t2.time as time2, t2.device_id as device2, t2.temperature as temperature2 FROM table1 t1 ASOF LEFT JOIN table2 t2 ON t1.time>=t2.time order by time1; +``` + +查询结果 + +```SQL ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +| time1|device1|temperature1| time2|device2|temperature2| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0|2024-11-26T13:37:00.000+08:00| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0|2024-11-26T13:37:00.000+08:00| 100| 90.0| +|2024-11-27T16:38:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:39:00.000+08:00| 101| 85.0|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:40:00.000+08:00| 101| 85.0|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:41:00.000+08:00| 101| 85.0|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:42:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:43:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:44:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-28T08:00:00.000+08:00| 100| 85.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-28T09:00:00.000+08:00| 100| null|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-28T10:00:00.000+08:00| 100| 85.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-28T11:00:00.000+08:00| 100| 88.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-29T10:00:00.000+08:00| 101| 85.0|2024-11-29T00:00:00.000+08:00| 101| 85.0| +|2024-11-29T11:00:00.000+08:00| 100| null|2024-11-29T11:00:00.000+08:00| 100| null| +|2024-11-29T18:30:00.000+08:00| 100| 90.0|2024-11-29T11:00:00.000+08:00| 100| null| +|2024-11-30T09:30:00.000+08:00| 101| 90.0|2024-11-30T00:00:00.000+08:00| 101| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-30T00:00:00.000+08:00| 101| 90.0| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +Total line number = 18 +It costs 0.058s +``` + +示例2:plant\_id 相同且 table1 中时间戳大于等于 table2 时间戳且时间戳最接近 + +```SQL +SELECT t1.time as time1, t1.plant_id as plant1, t1.temperature as temperature1, t2.time as time2, t2.plant_id as plant2, t2.temperature as temperature2 FROM table1 t1 ASOF LEFT JOIN table2 t2 ON t1.plant_id=t2.plant_id and t1.time>=t2.time ORDER BY time1; +``` + +查询结果 + +```SQL ++-----------------------------+------+------------+-----------------------------+------+------------+ +| time1|plant1|temperature1| time2|plant2|temperature2| ++-----------------------------+------+------------+-----------------------------+------+------------+ +|2024-11-26T13:37:00.000+08:00| 1001| 90.0|2024-11-26T13:37:00.000+08:00| 1001| 90.0| +|2024-11-26T13:38:00.000+08:00| 1001| 90.0|2024-11-26T13:37:00.000+08:00| 1001| 90.0| +|2024-11-27T16:38:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:39:00.000+08:00| 1001| 85.0|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:40:00.000+08:00| 1001| 85.0|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:41:00.000+08:00| 1001| 85.0|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:42:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:43:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:44:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-28T08:00:00.000+08:00| 3001| 85.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-28T09:00:00.000+08:00| 3001| null|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-28T10:00:00.000+08:00| 3001| 85.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-28T11:00:00.000+08:00| 3001| 88.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-29T10:00:00.000+08:00| 3001| 85.0|2024-11-29T00:00:00.000+08:00| 3001| 85.0| +|2024-11-29T11:00:00.000+08:00| 3002| null|2024-11-29T11:00:00.000+08:00| 3002| null| +|2024-11-29T18:30:00.000+08:00| 3002| 90.0|2024-11-29T11:00:00.000+08:00| 3002| null| +|2024-11-30T09:30:00.000+08:00| 3002| 90.0|2024-11-30T00:00:00.000+08:00| 3002| 90.0| +|2024-11-30T14:30:00.000+08:00| 3002| 90.0|2024-11-30T00:00:00.000+08:00| 3002| 90.0| ++-----------------------------+------+------------+-----------------------------+------+------------+ +Total line number = 18 +It costs 0.022s +``` diff --git a/src/zh/UserGuide/latest-Table/SQL-Manual/From-Join-Clause.md b/src/zh/UserGuide/latest-Table/SQL-Manual/From-Join-Clause.md index 0ad97598f..4daa47dac 100644 --- a/src/zh/UserGuide/latest-Table/SQL-Manual/From-Join-Clause.md +++ b/src/zh/UserGuide/latest-Table/SQL-Manual/From-Join-Clause.md @@ -33,7 +33,7 @@ relation joinType : INNER? - | FULL OUTER? + | OUTER? | CROSS? | ASOF? ; @@ -72,8 +72,8 @@ JOIN 用于将两个表基于某些条件连接起来,通常,连接条件是 在当前版本的 IoTDB 中,支持以下连接方式: -* 内连接(Inner Join),连接条件只能是时间列的等值连接。 -* 全外连接(Full Outer Join),连接条件可以是任意等值表达式。 +* 内连接(Inner Join),连接条件可以是任意等值表达式。 +- 外连接(Outer Join),连接条件可以是任意等值表达式。 * 交叉连接(Cross Join) * ASOF JOIN(AS OF a specific point in time,特定时间点),是一种基于时间或近似匹配条件的特殊连接操作,适用于两个数据集的时间戳不完全对齐的场景。它能够为左表的每一行找到右表中时间最接近且满足条件的对应行,常用于处理时间序列数据(如传感器数据、金融行情等)。 @@ -120,7 +120,47 @@ SELECT selectExpr [, selectExpr] ... FROM [, ] ... [WHE - RIGHT(右侧表的所有行至少出现一次) - FULL(两个表的所有行至少出现一次) -在当前版本的 IoTDB 中,只支持 FULL [OUTER] JOIN,即全外连接,返回左表和右表连接后的所有记录。如果某个表中的记录没有与另一个表中的记录匹配,则会返回 NULL 值。__FULL JOIN 只能使用显式连接方式。__ +#### 3.2.1 左外连接 + +LEFT [OUTER] JOIN,即左外连接,返回左表中的所有记录,以及右表中与左表满足连接条件的记录。对于右表中没有与左表匹配的记录返回NULL值。因为需要指定LEFT JOIN关键字,所以左外连接一般只使用显示连接的语法,即在ON或USING后指定连接条件。 + +> V 2.0.5 及以后版本支持 + +SQL语法如下所示: + +```SQL +// 显示连接, 在ON关键字后指定连接条件或在Using关键字后指定连接列 +SELECT selectExpr [, selectExpr] ... FROM LEFT [OUTER] JOIN joinCriteria [WHERE whereCondition] + +joinCriteria + : ON booleanExpression + | USING '(' identifier (',' identifier)* ')' + ; +``` + +#### 3.2.2 右外连接 + +RIGHT [OUTER] JOIN, 即右外连接,返回右表中的所有记录,以及左表中与右表满足连接条件的记录。对于左表中没有与右表匹配的记录返回NULL值。 + +> V 2.0.5 及以后版本支持 + +RIGHT JOIN与LEFT JOIN是“对称”的操作,通常情况下,使用 `LEFT JOIN` 比较常见,因为在实际应用中通常更关心左表的数据。而且`RIGHT JOIN` 总可以转换为`LEFT JOIN` ,即`A RIGHT JOIN B ON A.id=B.id` 的查询结果与 `B LEFT JOIN A on B.id = A.id`是等价的。 + +SQL语法如下所示: + +```SQL +// 在ON关键字后指定连接条件或在Using关键字后指定连接列 +SELECT selectExpr [, selectExpr] ... FROM RIGHT [OUTER] JOIN joinCriteria [WHERE whereCondition] + +joinCriteria + : ON booleanExpression + | USING '(' identifier (',' identifier)* ')' + ; +``` + +#### 3.2.3 全外连接 + +FULL [OUTER] JOIN,即全外连接,返回左表和右表连接后的所有记录。如果某个表中的记录没有与另一个表中的记录匹配,则会返回 NULL 值。__FULL JOIN 只能使用显式连接方式。__ SQL语法如下所示: @@ -139,13 +179,14 @@ joinCriteria ### 3.4 非精确点连接(​ASOF JOIN​) -IoTDB ASOF JOIN 即非精确点连接方式,允许用户按照指定的规则以时间戳最接近的方式进行匹配。**目前版本只支持针对 Time 列的 ASOF INNER JOIN。** +IoTDB ASOF JOIN 即非精确点连接方式,允许用户按照指定的规则以时间戳最接近的方式进行匹配。**目前版本只支持 ASOF INNER/LEFT JOIN。** +> ASOF LEFT JOIN 方式 V2.0.5 及以后版本支持 SQL语法如下所示: ```SQL SELECT selectExpr [, selectExpr] ... FROM - ASOF[(tolerance theta)] [INNER] JOIN joinCriteria + ASOF[(tolerance theta)] [INNER|LEFT] JOIN joinCriteria [WHERE whereCondition] WHERE a.time = tolerance(b.time, 1s) @@ -161,7 +202,7 @@ comparisonOperator **说明:** * ASOF JOIN 默认使用 ASOF INNER JOIN 实现 -* 当使用 ON 关键字进行连接时,连接条件里必须包含针对 Time 列的不等式连接条件,不等式仅支持 `">", ">=", "<", "<="` 四种操作符,其代表的连接匹配规则如下:其中 lt 表示 left table, rt 表示 right table +* 当使用 ON 关键字进行连接时,连接条件里必须包含左右均为 TIMESTAMP 类型的不等式连接条件(即主连接条件),不等式仅支持 `">", ">=", "<", "<="` 四种操作符,其代表的连接匹配规则如下:其中 lt 表示 left table, rt 表示 right table | 运算符 | 连接方式 | | -------------------------- | ---------------------------------------------- | @@ -171,8 +212,51 @@ comparisonOperator | `lt.time < rt.time` | 左表中时间戳小于右表时间戳且时间戳最接近 | * Tolerance 参数:容差,表示右表数据查找允许的最大时间差。(用 TimeDuration 表示,如 1d 表示1天)。如果不指定 Tolerance 参数,则表示查找时间范围为​**正无穷**​。注意:目前仅 ASOF **INNER** JOIN 中支持该参数 +* ASOF 除了主连接条件外,还可以指定针对其它列(ID、Attribute、Measurement)的等值连接条件,表示查询结果按照其它列进行分组。主连接条件必须**放在最后**,并且主连接条件与其他条件(如果有的话)之间必须使用"AND"进行连接。 + +### 3.5 半连接/反连接(SEMI JOIN/ANTI-SEMI JOIN) +半连接是一种特殊的连接操作,其目的是确定一个表中的行是否存在于另一个表中。半连接返回的结果集包含符合连接条件的第一个表的行,而不包含第二个表的实际数据。与半连接对应的是反连接,反连接目的是确定两个表之间没有匹配的行。反连接返回的结果集包含满足连接条件的第一个表中的行,但不包含第二个表中与之匹配的行。 +在IoTDB表模型中,不提供\`SEMI JOIN\`语法,支持使用 IN 子查询或 EXISTS 子查询来实现半连接;同样,也不提供\`ANTI SEMI JOIN\`语法,支持使用 NOT IN 或 NOT EXISTS 子查询来实现反连接。关于子查询详细说明可参考[嵌套查询](../SQL-Manual/Nested-Queries.md) + +* 半连接语法示例如下: + +```SQL +// 使用IN实现半连接 +SELECT * +FROM table1 +WHERE time IN (SELECT time FROM table2); + +// 使用EXISTS实现半连接 +SELECT * +FROM table1 t1 +WHERE EXISTS (SELECT 1 FROM table2 t2 WHERE t1.time = t2.time); + +// 等同于其他数据库的SEMI JOIN语法 +SELECT table1.* +FROM table1 SEMI JOIN table2 +on table1.time=table2.time; +``` + +* 反连接语法示例如下: + +```SQL +// 使用NOT IN实现反连接 +SELECT * +FROM table1 +WHERE time NOT IN (SELECT time FROM table2); + +// 使用NOT EXISTS实现反连接 +SELECT * +FROM table1 t1 +WHERE NOT EXISTS (SELECT 1 FROM table2 t2 WHERE t1.time = t2.time); + +// 等同于其他数据库的ANTI SEMI JOIN语法 +SELECT table1.* +FROM table1 ANTI JOIN table2 +on table1.time=table2.time; +``` ## 4. 示例数据 @@ -351,8 +435,272 @@ Total line number = 3 It costs 0.082s ``` +示例4:非 time 列等值连接 + +```SQL +SELECT + t1.time, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 JOIN table2 t2 +ON t1.device_id = t2.device_id +ORDER BY t1.time +LIMIT 10 +``` + +查询结果: + +```SQL ++-----------------------------+-------+------------+-------+------------+ +| time|device1|temperature1|device2|temperature2| ++-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| null| +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 85.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| 100| null| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| 100| 85.0| +|2024-11-27T16:38:00.000+08:00| 101| null| 101| 90.0| +|2024-11-27T16:38:00.000+08:00| 101| null| 101| 85.0| +|2024-11-27T16:38:00.000+08:00| 101| null| 101| 85.0| +|2024-11-27T16:39:00.000+08:00| 101| 85.0| 101| 90.0| ++-----------------------------+-------+------------+-------+------------+ +Total line number = 10 +It costs 0.030s +``` + + #### 4.2.2 Outer Join +1. LEFT JOIN + +示例 1:显式连接 + +```SQL +SELECT + t1.time as time1, t2.time as time2, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 LEFT JOIN table2 t2 +ON t1.time = t2.time +``` + +查询结果: + +```SQL ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +| time1| time2|device1|temperature1|device2|temperature2| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| null| 100| 90.0| null| null| +|2024-11-27T16:38:00.000+08:00| null| 101| null| null| null| +|2024-11-27T16:39:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-27T16:40:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-27T16:41:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-27T16:42:00.000+08:00| null| 101| null| null| null| +|2024-11-27T16:43:00.000+08:00| null| 101| null| null| null| +|2024-11-27T16:44:00.000+08:00| null| 101| null| null| null| +|2024-11-28T08:00:00.000+08:00|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +|2024-11-28T09:00:00.000+08:00| null| 100| null| null| null| +|2024-11-28T10:00:00.000+08:00| null| 100| 85.0| null| null| +|2024-11-28T11:00:00.000+08:00| null| 100| 88.0| null| null| +|2024-11-29T10:00:00.000+08:00| null| 101| 85.0| null| null| +|2024-11-29T11:00:00.000+08:00|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +|2024-11-29T18:30:00.000+08:00| null| 100| 90.0| null| null| +|2024-11-30T09:30:00.000+08:00| null| 101| 90.0| null| null| +|2024-11-30T14:30:00.000+08:00| null| 101| 90.0| null| null| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +Total line number = 18 +It costs 0.031s +``` + +示例 2:显式连接 + +```SQL +SELECT + time, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 LEFT JOIN table2 t2 +USING(time) +``` + +查询结果: + +```SQL ++-----------------------------+-------+------------+-------+------------+ +| time|device1|temperature1|device2|temperature2| ++-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0| null| null| +|2024-11-27T16:38:00.000+08:00| 101| null| null| null| +|2024-11-27T16:39:00.000+08:00| 101| 85.0| null| null| +|2024-11-27T16:40:00.000+08:00| 101| 85.0| null| null| +|2024-11-27T16:41:00.000+08:00| 101| 85.0| null| null| +|2024-11-27T16:42:00.000+08:00| 101| null| null| null| +|2024-11-27T16:43:00.000+08:00| 101| null| null| null| +|2024-11-27T16:44:00.000+08:00| 101| null| null| null| +|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +|2024-11-28T09:00:00.000+08:00| 100| null| null| null| +|2024-11-28T10:00:00.000+08:00| 100| 85.0| null| null| +|2024-11-28T11:00:00.000+08:00| 100| 88.0| null| null| +|2024-11-29T10:00:00.000+08:00| 101| 85.0| null| null| +|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +|2024-11-29T18:30:00.000+08:00| 100| 90.0| null| null| +|2024-11-30T09:30:00.000+08:00| 101| 90.0| null| null| +|2024-11-30T14:30:00.000+08:00| 101| 90.0| null| null| ++-----------------------------+-------+------------+-------+------------+ +Total line number = 18 +It costs 0.031s +``` + +示例3:连接条件为非time列 + +```SQL +SELECT + region, + t1.time as time1, + t1.temperature as temperature1, + t2.time as time2, + t2.temperature as temperature2 +FROM + table1 t1 LEFT JOIN table2 t2 +USING(region) +LIMIT 10 +``` + +查询结果: + +```SQL ++------+-----------------------------+------------+-----------------------------+------------+ +|region| time1|temperature1| time2|temperature2| ++------+-----------------------------+------------+-----------------------------+------------+ +| 上海|2024-11-29T11:00:00.000+08:00| null|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-29T11:00:00.000+08:00| null|2024-11-28T08:00:00.000+08:00| 85.0| +| 上海|2024-11-29T11:00:00.000+08:00| null|2024-11-30T00:00:00.000+08:00| 90.0| +| 上海|2024-11-29T11:00:00.000+08:00| null|2024-11-29T00:00:00.000+08:00| 85.0| +| 上海|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-28T08:00:00.000+08:00| 85.0| +| 上海|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-30T00:00:00.000+08:00| 90.0| +| 上海|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-29T00:00:00.000+08:00| 85.0| +| 上海|2024-11-29T18:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-29T18:30:00.000+08:00| 90.0|2024-11-28T08:00:00.000+08:00| 85.0| ++------+-----------------------------+------------+-----------------------------+------------+ +Total line number = 10 +It costs 0.038s +``` + +2. RIGHT JOIN + +示例 1:显式连接 + +```SQL +SELECT + t1.time as time1, t2.time as time2, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 RIGHT JOIN table2 t2 +ON t1.time = t2.time +``` + +查询结果: + +```SQL ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +| time1| time2|device1|temperature1|device2|temperature2| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +| null|2024-11-27T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-28T08:00:00.000+08:00|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +| null|2024-11-29T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-29T11:00:00.000+08:00|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +| null|2024-11-30T00:00:00.000+08:00| null| null| 101| 90.0| ++-----------------------------+-----------------------------+-------+------------+-------+------------+ +Total line number = 6 +It costs 0.030s +``` + +示例 2:显式连接 + +```SQL +SELECT + time, + t1.device_id as device1, + t1.temperature as temperature1, + t2.device_id as device2, + t2.temperature as temperature2 +FROM + table1 t1 RIGHT JOIN table2 t2 +USING(time) +``` + +查询结果: + +```SQL ++-----------------------------+-------+------------+-------+------------+ +| time|device1|temperature1|device2|temperature2| ++-----------------------------+-------+------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0| 100| 90.0| +|2024-11-27T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-28T08:00:00.000+08:00| 100| 85.0| 100| 85.0| +|2024-11-29T00:00:00.000+08:00| null| null| 101| 85.0| +|2024-11-29T11:00:00.000+08:00| 100| null| 100| null| +|2024-11-30T00:00:00.000+08:00| null| null| 101| 90.0| ++-----------------------------+-------+------------+-------+------------+ +Total line number = 6 +It costs 0.053s +``` + +示例3:连接条件为非time列 + +```SQL +SELECT + region, + t1.time as time1, + t1.temperature as temperature1, + t2.time as time2, + t2.temperature as temperature2 +FROM + table1 t1 RIGHT JOIN table2 t2 +USING(region) +LIMIT 10 +``` + +查询结果: + +```SQL ++------+-----------------------------+------------+-----------------------------+------------+ +|region| time1|temperature1| time2|temperature2| ++------+-----------------------------+------------+-----------------------------+------------+ +| 上海|2024-11-29T11:00:00.000+08:00| null|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-30T09:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-29T18:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-28T08:00:00.000+08:00| 85.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-30T14:30:00.000+08:00| 90.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-29T10:00:00.000+08:00| 85.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-28T09:00:00.000+08:00| null|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-28T10:00:00.000+08:00| 85.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-28T11:00:00.000+08:00| 88.0|2024-11-29T11:00:00.000+08:00| null| +| 上海|2024-11-29T11:00:00.000+08:00| null|2024-11-28T08:00:00.000+08:00| 85.0| ++------+-----------------------------+------------+-----------------------------+------------+ +Total line number = 10 +It costs 0.029s +``` + +3. FULL JOIN + 示例 1:显式连接 ```sql @@ -535,6 +883,8 @@ It costs 0.047s #### 4.2.4 Asof join +1. ASOF INNER JOIN + 示例1:不指定 Tolerance 参数,且 table1 中时间戳大于等于 table2 时间戳且时间戳最接近 ```SQL @@ -585,3 +935,119 @@ SELECT t1.time as time1, t1.device_id as device1, t1.temperature as temperature1 |2024-11-26T13:37:00.000+08:00| 100| 90.0|2024-11-26T13:37:00.000+08:00| 100| 90.0| +-----------------------------+-------+------------+-----------------------------+-------+------------+ ``` +示例3:指定 Tolerance 参数,plant\_id 相同且 table1 中时间戳大于等于 table2 时间戳且时间戳最接近 + +```SQL +SELECT t1.time as time1, t1.plant_id as plant1, t1.temperature as temperature1, t2.time as time2, t2.plant_id as plant2, t2.temperature as temperature2 FROM table1 t1 ASOF(tolerance 2s) JOIN table2 t2 ON t1.plant_id=t2.plant_id and t1.time>=t2.time; +``` + +查询结果 + +```SQL ++-----------------------------+------+------------+-----------------------------+------+------------+ +| time1|plant1|temperature1| time2|plant2|temperature2| ++-----------------------------+------+------------+-----------------------------+------+------------+ +|2024-11-26T13:37:00.000+08:00| 1001| 90.0|2024-11-26T13:37:00.000+08:00| 1001| 90.0| +|2024-11-28T08:00:00.000+08:00| 3001| 85.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-29T11:00:00.000+08:00| 3002| null|2024-11-29T11:00:00.000+08:00| 3002| null| ++-----------------------------+------+------------+-----------------------------+------+------------+ +Total line number = 3 +It costs 0.046s +``` + +示例4: 今天某时间段与上周某时间段的 asof join + +```SQL +SELECT * FROM (SELECT time, device_id AS device1, temperature AS temperature1 FROM table1 ) AS t1 ASOF JOIN (SELECT time, device_id AS device2, temperature AS temperature2 FROM table1) AS t2 ON t1.time>date_bin(1w, t2.time) limit 10 +``` + +查询结果: + +```SQL ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +| time|device1|temperature1| time|device2|temperature2| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-29T11:00:00.000+08:00| 100| null| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-30T09:30:00.000+08:00| 101| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-29T18:30:00.000+08:00| 100| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-30T14:30:00.000+08:00| 101| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-29T10:00:00.000+08:00| 101| 85.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T09:00:00.000+08:00| 100| null| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T10:00:00.000+08:00| 100| 85.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-28T11:00:00.000+08:00| 100| 88.0| +|2024-11-30T09:30:00.000+08:00| 101| 90.0|2024-11-29T11:00:00.000+08:00| 100| null| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +``` + +2. ASOF LEFT JOIN + +示例1:table1 中时间戳大于等于 table2 时间戳且时间戳最接近 + +```SQL +SELECT t1.time as time1, t1.device_id as device1, t1.temperature as temperature1, t2.time as time2, t2.device_id as device2, t2.temperature as temperature2 FROM table1 t1 ASOF LEFT JOIN table2 t2 ON t1.time>=t2.time order by time1; +``` + +查询结果 + +```SQL ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +| time1|device1|temperature1| time2|device2|temperature2| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +|2024-11-26T13:37:00.000+08:00| 100| 90.0|2024-11-26T13:37:00.000+08:00| 100| 90.0| +|2024-11-26T13:38:00.000+08:00| 100| 90.0|2024-11-26T13:37:00.000+08:00| 100| 90.0| +|2024-11-27T16:38:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:39:00.000+08:00| 101| 85.0|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:40:00.000+08:00| 101| 85.0|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:41:00.000+08:00| 101| 85.0|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:42:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:43:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-27T16:44:00.000+08:00| 101| null|2024-11-27T00:00:00.000+08:00| 101| 85.0| +|2024-11-28T08:00:00.000+08:00| 100| 85.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-28T09:00:00.000+08:00| 100| null|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-28T10:00:00.000+08:00| 100| 85.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-28T11:00:00.000+08:00| 100| 88.0|2024-11-28T08:00:00.000+08:00| 100| 85.0| +|2024-11-29T10:00:00.000+08:00| 101| 85.0|2024-11-29T00:00:00.000+08:00| 101| 85.0| +|2024-11-29T11:00:00.000+08:00| 100| null|2024-11-29T11:00:00.000+08:00| 100| null| +|2024-11-29T18:30:00.000+08:00| 100| 90.0|2024-11-29T11:00:00.000+08:00| 100| null| +|2024-11-30T09:30:00.000+08:00| 101| 90.0|2024-11-30T00:00:00.000+08:00| 101| 90.0| +|2024-11-30T14:30:00.000+08:00| 101| 90.0|2024-11-30T00:00:00.000+08:00| 101| 90.0| ++-----------------------------+-------+------------+-----------------------------+-------+------------+ +Total line number = 18 +It costs 0.058s +``` + +示例2:plant\_id 相同且 table1 中时间戳大于等于 table2 时间戳且时间戳最接近 + +```SQL +SELECT t1.time as time1, t1.plant_id as plant1, t1.temperature as temperature1, t2.time as time2, t2.plant_id as plant2, t2.temperature as temperature2 FROM table1 t1 ASOF LEFT JOIN table2 t2 ON t1.plant_id=t2.plant_id and t1.time>=t2.time ORDER BY time1; +``` + +查询结果 + +```SQL ++-----------------------------+------+------------+-----------------------------+------+------------+ +| time1|plant1|temperature1| time2|plant2|temperature2| ++-----------------------------+------+------------+-----------------------------+------+------------+ +|2024-11-26T13:37:00.000+08:00| 1001| 90.0|2024-11-26T13:37:00.000+08:00| 1001| 90.0| +|2024-11-26T13:38:00.000+08:00| 1001| 90.0|2024-11-26T13:37:00.000+08:00| 1001| 90.0| +|2024-11-27T16:38:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:39:00.000+08:00| 1001| 85.0|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:40:00.000+08:00| 1001| 85.0|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:41:00.000+08:00| 1001| 85.0|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:42:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:43:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-27T16:44:00.000+08:00| 1001| null|2024-11-27T00:00:00.000+08:00| 1001| 85.0| +|2024-11-28T08:00:00.000+08:00| 3001| 85.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-28T09:00:00.000+08:00| 3001| null|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-28T10:00:00.000+08:00| 3001| 85.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-28T11:00:00.000+08:00| 3001| 88.0|2024-11-28T08:00:00.000+08:00| 3001| 85.0| +|2024-11-29T10:00:00.000+08:00| 3001| 85.0|2024-11-29T00:00:00.000+08:00| 3001| 85.0| +|2024-11-29T11:00:00.000+08:00| 3002| null|2024-11-29T11:00:00.000+08:00| 3002| null| +|2024-11-29T18:30:00.000+08:00| 3002| 90.0|2024-11-29T11:00:00.000+08:00| 3002| null| +|2024-11-30T09:30:00.000+08:00| 3002| 90.0|2024-11-30T00:00:00.000+08:00| 3002| 90.0| +|2024-11-30T14:30:00.000+08:00| 3002| 90.0|2024-11-30T00:00:00.000+08:00| 3002| 90.0| ++-----------------------------+------+------------+-----------------------------+------+------------+ +Total line number = 18 +It costs 0.022s +```