From 90dc6220e40eabd00c54912d10c5ded8203a3b98 Mon Sep 17 00:00:00 2001 From: Jing Date: Thu, 26 Aug 2021 19:11:39 +0800 Subject: [PATCH 1/6] [FLINK-23287][docs][table] Create user document for Window Join in SQL --- .../docs/dev/table/sql/queries/window-join.md | 192 ++++++++++++++++++ .../docs/dev/table/sql/queries/window-tvf.md | 2 +- .../docs/dev/table/sql/queries/window-join.md | 192 ++++++++++++++++++ .../docs/dev/table/sql/queries/window-tvf.md | 2 +- 4 files changed, 386 insertions(+), 2 deletions(-) create mode 100644 docs/content.zh/docs/dev/table/sql/queries/window-join.md create mode 100644 docs/content/docs/dev/table/sql/queries/window-join.md diff --git a/docs/content.zh/docs/dev/table/sql/queries/window-join.md b/docs/content.zh/docs/dev/table/sql/queries/window-join.md new file mode 100644 index 0000000000000..4a1a230995ec9 --- /dev/null +++ b/docs/content.zh/docs/dev/table/sql/queries/window-join.md @@ -0,0 +1,192 @@ +--- +title: "窗口关联" +weight: 15 +type: docs +--- + + +# Window JOIN +{{< label Streaming >}} + +A window join adds the dimension of time into the join criteria themselves. In doing so, the window join joins the elements of two streams that share a common key and lie in the same window. The semantic of window join is same to the [DataStream window join]({{< ref "docs/dev/datastream/operators/joining" >}}#Window Join) + +For streaming queries, unlike other joins on continuous tables, window join does not emit intermediate results but only emits final results at the end of the window. Moreover, window join purge all intermediate state when no longer needed. + +Usually, Window join is used with [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}). Besides, Window join could follow after other operations based on [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}), such as [Window Aggregation]({{< ref "docs/dev/table/sql/queries/window-agg" >}}), [Window TopN]({{< ref "docs/dev/table/sql/queries/window-topn">}}) and [Window Join]({{< ref "docs/dev/table/sql/queries/window-join">}}). + +Currently, Window join requires the join on condition contains window starts equality of input tables and window ends equality of input tables. + +The following shows the syntax of the Window join statement: + +```sql +SELECT ... +FROM L [LEFT|RIGHT|FULL OUTER] JOIN R -- L and R are relations applied windowing TVF +ON L.window_start = R.window_start AND L.window_end = R.window_end AND ... +``` + +Window join supports INNER/LEFT/RIGHT/FULL OUTER/ANTI/SEMI JOIN. + +## INNER/LEFT/RIGHT/FULL OUTER + +The syntax of INNER/LEFT/RIGHT/FULL OUTER WINDOW JOIN are very similar with each other, we only give an example for FULL OUTER JOIN here. +When performing a window join, all elements with a common key and a common tumbling window are joined together. We only give an example for a Window join which works on a Tumble Window TVF. +By scoping the region of time for the join into fixed five-minute intervals, we chopped our datasets into two distinct windows of time: [12:00, 12:05) and [12:05, 12:10). The L2 and R2 rows could not join together because they fell into separate windows. + +```sql +Flink SQL> desc LeftTable; ++-------------+------------------------+------+-----+--------+---------------------------------+ +| name | type | null | key | extras | watermark | ++-------------+------------------------+------+-----+--------+---------------------------------+ +| `Time` | TIMESTAMP(3) *ROWTIME* | true | | | `Time` - INTERVAL '1' SECOND | +| Num | Int | true | | | | +| Id | STRING | true | | | | ++-------------+------------------------+------+-----+--------+---------------------------------+ + +Flink SQL> SELECT * FROM LeftTable; ++------------------+-------+------+ +| `Time` | Num | Id | ++------------------+-------+------+ +| 2020-04-15 12:02 | 1 | L1 | +| 2020-04-15 12:06 | 2 | L2 | +| 2020-04-15 12:03 | 3 | L3 | ++------------------+-------+------+ + +Flink SQL> desc RightTable; ++-------------+------------------------+------+-----+--------+---------------------------------+ +| name | type | null | key | extras | watermark | ++-------------+------------------------+------+-----+--------+---------------------------------+ +| `Time` | TIMESTAMP(3) *ROWTIME* | true | | | `Time` - INTERVAL '1' SECOND | +| Num | Int | true | | | | +| Id | STRING | true | | | | ++-------------+------------------------+------+-----+--------+---------------------------------+ + +Flink SQL> SELECT * FROM RightTable; ++------------------+-------+------+ +| `Time` | Num | Id | ++------------------+-------+------+ +| 2020-04-15 12:01 | 2 | R2 | +| 2020-04-15 12:04 | 3 | R3 | +| 2020-04-15 12:05 | 4 | R4 | ++------------------+-------+------+ + +Flink SQL> SELECT L.Id as L, R.Id as R, L.window_start, L.window_end + FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) L + FULL JOIN ( + SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) R + ON L.Num = R.Num AND L.window_start = R.window_start AND L.window_end = R.window_end; ++--------+--------+---------------------+---------------------+ +| L | R | window_start | window_end | ++--------+--------+---------------------+---------------------+ +| L1 | null | 2020-04-15 12:00 | 2020-04-15 12:05 | +| null | R2 | 2020-04-15 12:00 | 2020-04-15 12:05 | +| L3 | R3 | 2020-04-15 12:00 | 2020-04-15 12:05 | +| L2 | null | 2020-04-15 12:05 | 2020-04-15 12:10 | +| null | R4 | 2020-04-15 12:05 | 2020-04-15 12:10 | ++--------+--------+---------------------+---------------------+ +``` + +*Note: in order to better understand the behavior of windowing, we simplify the displaying of timestamp values to not show the trailing zeros, e.g. `2020-04-15 08:05` should be displayed as `2020-04-15 08:05:00.000` in Flink SQL Client if the type is `TIMESTAMP(3)`.* + + +## SEMI +Semi Window Joins returns a row from one left record if there is at least one matching row on the right side within the common window. + +```sql +Flink SQL> SELECT * + FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) L WHERE L.Num IN ( + SELECT Num FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) R WHERE L.window_start = R.window_start AND L.window_end = R.window_end); ++------------------+-------+------+------------------+------------------+-------------------------+ +| `Time` | Num | Id | window_start | window_end | window_time | ++------------------+-------+------+------------------+------------------+-------------------------+ +| 2020-04-15 12:03 | 3 | L3 | 2020-04-15 12:00 | 2020-04-15 12:05 | 2020-04-15 12:04:59.999 | ++------------------+-------+------+------------------+------------------+-------------------------+ + +Flink SQL> SELECT * + FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) L WHERE EXISTS ( + SELECT * FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) R WHERE L.Num = R.Num AND L.window_start = R.window_start AND L.window_end = R.window_end); ++------------------+-------+------+------------------+------------------+-------------------------+ +| `Time` | Num | Id | window_start | window_end | window_time | ++------------------+-------+------+------------------+------------------+-------------------------+ +| 2020-04-15 12:03 | 3 | L3 | 2020-04-15 12:00 | 2020-04-15 12:05 | 2020-04-15 12:04:59.999 | ++------------------+-------+------+------------------+------------------+-------------------------+ +``` + +*Note: in order to better understand the behavior of windowing, we simplify the displaying of timestamp values to not show the trailing zeros, e.g. `2020-04-15 08:05` should be displayed as `2020-04-15 08:05:00.000` in Flink SQL Client if the type is `TIMESTAMP(3)`.* + + +## ANTI +Anti Window Joins are the obverse of the Inner Window join: they contain all of the unjoined rows within each common window. + +```sql +Flink SQL> SELECT * + FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) L WHERE L.Num NOT IN ( + SELECT Num FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) R WHERE L.window_start = R.window_start AND L.window_end = R.window_end); ++------------------+-------+------+------------------+------------------+-------------------------+ +| `Time` | Num | Id | window_start | window_end | window_time | ++------------------+-------+------+------------------+------------------+-------------------------+ +| 2020-04-15 12:02 | 1 | L1 | 2020-04-15 12:00 | 2020-04-15 12:05 | 2020-04-15 12:04:59.999 | +| 2020-04-15 12:06 | 2 | L2 | 2020-04-15 12:05 | 2020-04-15 12:10 | 2020-04-15 12:09:59.999 | ++------------------+-------+------+------------------+------------------+-------------------------+ + +Flink SQL> SELECT * + FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) L WHERE NOT EXISTS ( + SELECT * FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) R WHERE L.Num = R.Num AND L.window_start = R.window_start AND L.window_end = R.window_end); ++------------------+-------+------+------------------+------------------+-------------------------+ +| `Time` | Num | Id | window_start | window_end | window_time | ++------------------+-------+------+------------------+------------------+-------------------------+ +| 2020-04-15 12:02 | 1 | L1 | 2020-04-15 12:00 | 2020-04-15 12:05 | 2020-04-15 12:04:59.999 | +| 2020-04-15 12:06 | 2 | L2 | 2020-04-15 12:05 | 2020-04-15 12:10 | 2020-04-15 12:09:59.999 | ++------------------+-------+------+------------------+------------------+-------------------------+ +``` + +*Note: in order to better understand the behavior of windowing, we simplify the displaying of timestamp values to not show the trailing zeros, e.g. `2020-04-15 08:05` should be displayed as `2020-04-15 08:05:00.000` in Flink SQL Client if the type is `TIMESTAMP(3)`.* + + +## Limitation + +### Limitation on Join clause +Currently, The window join requires the join on condition contains window starts equality of input tables and window ends equality of input tables. In the future, we can also simplify the join on clause to only include the window start equality if the windowing TVF is TUMBLE or HOP. + +### Limitation on windowing TVFs of inputs +Currently, the windowing TVFs must be the same of left and right inputs. This can be extended in the future, for example, tumbling windows join sliding windows with the same window size. + +### Limitation on Window join which follows after Windowing TVFs directly +Currently, if Window join follows after [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}), the [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}) has to be with Tumble Windows, Hop Windows or Cumulate Windows instead of Session windows. + +{{< top >}} diff --git a/docs/content.zh/docs/dev/table/sql/queries/window-tvf.md b/docs/content.zh/docs/dev/table/sql/queries/window-tvf.md index 211075768fc60..2cd172ea41065 100644 --- a/docs/content.zh/docs/dev/table/sql/queries/window-tvf.md +++ b/docs/content.zh/docs/dev/table/sql/queries/window-tvf.md @@ -44,7 +44,7 @@ Windowing TVFs is a replacement of legacy [Grouped Window Functions]({{< ref "do See more how to apply further computations based on windowing TVF: - [Window Aggregation]({{< ref "docs/dev/table/sql/queries/window-agg" >}}) - [Window TopN]({{< ref "docs/dev/table/sql/queries/window-topn">}}) -- Window Join (will be supported soon) +- [Window Join]({{< ref "docs/dev/table/sql/queries/window-join">}}) ## Window Functions diff --git a/docs/content/docs/dev/table/sql/queries/window-join.md b/docs/content/docs/dev/table/sql/queries/window-join.md new file mode 100644 index 0000000000000..3ad65a6fc0265 --- /dev/null +++ b/docs/content/docs/dev/table/sql/queries/window-join.md @@ -0,0 +1,192 @@ +--- +title: "Window JOIN" +weight: 15 +type: docs +--- + + +# Window JOIN +{{< label Streaming >}} + +A window join adds the dimension of time into the join criteria themselves. In doing so, the window join joins the elements of two streams that share a common key and lie in the same window. The semantic of window join is same to the [DataStream window join]({{< ref "docs/dev/datastream/operators/joining" >}}#Window Join) + +For streaming queries, unlike other joins on continuous tables, window join does not emit intermediate results but only emits final results at the end of the window. Moreover, window join purge all intermediate state when no longer needed. + +Usually, Window join is used with [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}). Besides, Window join could follow after other operations based on [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}), such as [Window Aggregation]({{< ref "docs/dev/table/sql/queries/window-agg" >}}), [Window TopN]({{< ref "docs/dev/table/sql/queries/window-topn">}}) and [Window Join]({{< ref "docs/dev/table/sql/queries/window-join">}}). + +Currently, Window join requires the join on condition contains window starts equality of input tables and window ends equality of input tables. + +The following shows the syntax of the Window join statement: + +```sql +SELECT ... +FROM L [LEFT|RIGHT|FULL OUTER] JOIN R -- L and R are relations applied windowing TVF +ON L.window_start = R.window_start AND L.window_end = R.window_end AND ... +``` + +Window join supports INNER/LEFT/RIGHT/FULL OUTER/ANTI/SEMI JOIN. + +## INNER/LEFT/RIGHT/FULL OUTER + +The syntax of INNER/LEFT/RIGHT/FULL OUTER WINDOW JOIN are very similar with each other, we only give an example for FULL OUTER JOIN here. +When performing a window join, all elements with a common key and a common tumbling window are joined together. We only give an example for a Window join which works on a Tumble Window TVF. +By scoping the region of time for the join into fixed five-minute intervals, we chopped our datasets into two distinct windows of time: [12:00, 12:05) and [12:05, 12:10). The L2 and R2 rows could not join together because they fell into separate windows. + +```sql +Flink SQL> desc LeftTable; ++-------------+------------------------+------+-----+--------+---------------------------------+ +| name | type | null | key | extras | watermark | ++-------------+------------------------+------+-----+--------+---------------------------------+ +| `Time` | TIMESTAMP(3) *ROWTIME* | true | | | `Time` - INTERVAL '1' SECOND | +| Num | Int | true | | | | +| Id | STRING | true | | | | ++-------------+------------------------+------+-----+--------+---------------------------------+ + +Flink SQL> SELECT * FROM LeftTable; ++------------------+-------+------+ +| `Time` | Num | Id | ++------------------+-------+------+ +| 2020-04-15 12:02 | 1 | L1 | +| 2020-04-15 12:06 | 2 | L2 | +| 2020-04-15 12:03 | 3 | L3 | ++------------------+-------+------+ + +Flink SQL> desc RightTable; ++-------------+------------------------+------+-----+--------+---------------------------------+ +| name | type | null | key | extras | watermark | ++-------------+------------------------+------+-----+--------+---------------------------------+ +| `Time` | TIMESTAMP(3) *ROWTIME* | true | | | `Time` - INTERVAL '1' SECOND | +| Num | Int | true | | | | +| Id | STRING | true | | | | ++-------------+------------------------+------+-----+--------+---------------------------------+ + +Flink SQL> SELECT * FROM RightTable; ++------------------+-------+------+ +| `Time` | Num | Id | ++------------------+-------+------+ +| 2020-04-15 12:01 | 2 | R2 | +| 2020-04-15 12:04 | 3 | R3 | +| 2020-04-15 12:05 | 4 | R4 | ++------------------+-------+------+ + +Flink SQL> SELECT L.Id as L, R.Id as R, L.window_start, L.window_end + FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) L + FULL JOIN ( + SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) R + ON L.Num = R.Num AND L.window_start = R.window_start AND L.window_end = R.window_end; ++--------+--------+---------------------+---------------------+ +| L | R | window_start | window_end | ++--------+--------+---------------------+---------------------+ +| L1 | null | 2020-04-15 12:00 | 2020-04-15 12:05 | +| null | R2 | 2020-04-15 12:00 | 2020-04-15 12:05 | +| L3 | R3 | 2020-04-15 12:00 | 2020-04-15 12:05 | +| L2 | null | 2020-04-15 12:05 | 2020-04-15 12:10 | +| null | R4 | 2020-04-15 12:05 | 2020-04-15 12:10 | ++--------+--------+---------------------+---------------------+ +``` + +*Note: in order to better understand the behavior of windowing, we simplify the displaying of timestamp values to not show the trailing zeros, e.g. `2020-04-15 08:05` should be displayed as `2020-04-15 08:05:00.000` in Flink SQL Client if the type is `TIMESTAMP(3)`.* + + +## SEMI +Semi Window Joins returns a row from one left record if there is at least one matching row on the right side within the common window. + +```sql +Flink SQL> SELECT * + FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) L WHERE L.Num IN ( + SELECT Num FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) R WHERE L.window_start = R.window_start AND L.window_end = R.window_end); ++------------------+-------+------+------------------+------------------+-------------------------+ +| `Time` | Num | Id | window_start | window_end | window_time | ++------------------+-------+------+------------------+------------------+-------------------------+ +| 2020-04-15 12:03 | 3 | L3 | 2020-04-15 12:00 | 2020-04-15 12:05 | 2020-04-15 12:04:59.999 | ++------------------+-------+------+------------------+------------------+-------------------------+ + +Flink SQL> SELECT * + FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) L WHERE EXISTS ( + SELECT * FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) R WHERE L.Num = R.Num AND L.window_start = R.window_start AND L.window_end = R.window_end); ++------------------+-------+------+------------------+------------------+-------------------------+ +| `Time` | Num | Id | window_start | window_end | window_time | ++------------------+-------+------+------------------+------------------+-------------------------+ +| 2020-04-15 12:03 | 3 | L3 | 2020-04-15 12:00 | 2020-04-15 12:05 | 2020-04-15 12:04:59.999 | ++------------------+-------+------+------------------+------------------+-------------------------+ +``` + +*Note: in order to better understand the behavior of windowing, we simplify the displaying of timestamp values to not show the trailing zeros, e.g. `2020-04-15 08:05` should be displayed as `2020-04-15 08:05:00.000` in Flink SQL Client if the type is `TIMESTAMP(3)`.* + + +## ANTI +Anti Window Joins are the obverse of the Inner Window join: they contain all of the unjoined rows within each common window. + +```sql +Flink SQL> SELECT * + FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) L WHERE L.Num NOT IN ( + SELECT Num FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) R WHERE L.window_start = R.window_start AND L.window_end = R.window_end); ++------------------+-------+------+------------------+------------------+-------------------------+ +| `Time` | Num | Id | window_start | window_end | window_time | ++------------------+-------+------+------------------+------------------+-------------------------+ +| 2020-04-15 12:02 | 1 | L1 | 2020-04-15 12:00 | 2020-04-15 12:05 | 2020-04-15 12:04:59.999 | +| 2020-04-15 12:06 | 2 | L2 | 2020-04-15 12:05 | 2020-04-15 12:10 | 2020-04-15 12:09:59.999 | ++------------------+-------+------+------------------+------------------+-------------------------+ + +Flink SQL> SELECT * + FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) L WHERE NOT EXISTS ( + SELECT * FROM ( + SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + ) R WHERE L.Num = R.Num AND L.window_start = R.window_start AND L.window_end = R.window_end); ++------------------+-------+------+------------------+------------------+-------------------------+ +| `Time` | Num | Id | window_start | window_end | window_time | ++------------------+-------+------+------------------+------------------+-------------------------+ +| 2020-04-15 12:02 | 1 | L1 | 2020-04-15 12:00 | 2020-04-15 12:05 | 2020-04-15 12:04:59.999 | +| 2020-04-15 12:06 | 2 | L2 | 2020-04-15 12:05 | 2020-04-15 12:10 | 2020-04-15 12:09:59.999 | ++------------------+-------+------+------------------+------------------+-------------------------+ +``` + +*Note: in order to better understand the behavior of windowing, we simplify the displaying of timestamp values to not show the trailing zeros, e.g. `2020-04-15 08:05` should be displayed as `2020-04-15 08:05:00.000` in Flink SQL Client if the type is `TIMESTAMP(3)`.* + + +## Limitation + +### Limitation on Join clause +Currently, The window join requires the join on condition contains window starts equality of input tables and window ends equality of input tables. In the future, we can also simplify the join on clause to only include the window start equality if the windowing TVF is TUMBLE or HOP. + +### Limitation on windowing TVFs of inputs +Currently, the windowing TVFs must be the same of left and right inputs. This can be extended in the future, for example, tumbling windows join sliding windows with the same window size. + +### Limitation on Window join which follows after Windowing TVFs directly +Currently, if Window join follows after [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}), the [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}) has to be with Tumble Windows, Hop Windows or Cumulate Windows instead of Session windows. + +{{< top >}} diff --git a/docs/content/docs/dev/table/sql/queries/window-tvf.md b/docs/content/docs/dev/table/sql/queries/window-tvf.md index e41922f3043cf..5cbde381f8d77 100644 --- a/docs/content/docs/dev/table/sql/queries/window-tvf.md +++ b/docs/content/docs/dev/table/sql/queries/window-tvf.md @@ -44,7 +44,7 @@ Windowing TVFs is a replacement of legacy [Grouped Window Functions]({{< ref "do See more how to apply further computations based on windowing TVF: - [Window Aggregation]({{< ref "docs/dev/table/sql/queries/window-agg" >}}) - [Window TopN]({{< ref "docs/dev/table/sql/queries/window-topn">}}) -- Window Join (will be supported soon) +- [Window Join]({{< ref "docs/dev/table/sql/queries/window-join">}}) ## Window Functions From 666e699b3690b9c90f424ce011d56f5a0cd48950 Mon Sep 17 00:00:00 2001 From: Jing Date: Fri, 27 Aug 2021 15:09:20 +0800 Subject: [PATCH 2/6] Minor updates --- .../docs/dev/table/sql/queries/window-join.md | 30 +++++++++---------- .../docs/dev/table/sql/queries/window-join.md | 30 +++++++++---------- 2 files changed, 30 insertions(+), 30 deletions(-) diff --git a/docs/content.zh/docs/dev/table/sql/queries/window-join.md b/docs/content.zh/docs/dev/table/sql/queries/window-join.md index 4a1a230995ec9..795b58a51843f 100644 --- a/docs/content.zh/docs/dev/table/sql/queries/window-join.md +++ b/docs/content.zh/docs/dev/table/sql/queries/window-join.md @@ -33,7 +33,11 @@ Usually, Window join is used with [Windowing TVF]({{< ref "docs/dev/table/sql/qu Currently, Window join requires the join on condition contains window starts equality of input tables and window ends equality of input tables. -The following shows the syntax of the Window join statement: +Window join supports INNER/LEFT/RIGHT/FULL OUTER/ANTI/SEMI JOIN. + +## INNER/LEFT/RIGHT/FULL OUTER + +The following shows the syntax of the INNER/LEFT/RIGHT/FULL OUTER Window join statement. ```sql SELECT ... @@ -41,10 +45,6 @@ FROM L [LEFT|RIGHT|FULL OUTER] JOIN R -- L and R are relations applied windowing ON L.window_start = R.window_start AND L.window_end = R.window_end AND ... ``` -Window join supports INNER/LEFT/RIGHT/FULL OUTER/ANTI/SEMI JOIN. - -## INNER/LEFT/RIGHT/FULL OUTER - The syntax of INNER/LEFT/RIGHT/FULL OUTER WINDOW JOIN are very similar with each other, we only give an example for FULL OUTER JOIN here. When performing a window join, all elements with a common key and a common tumbling window are joined together. We only give an example for a Window join which works on a Tumble Window TVF. By scoping the region of time for the join into fixed five-minute intervals, we chopped our datasets into two distinct windows of time: [12:00, 12:05) and [12:05, 12:10). The L2 and R2 rows could not join together because they fell into separate windows. @@ -86,7 +86,7 @@ Flink SQL> SELECT * FROM RightTable; | 2020-04-15 12:05 | 4 | R4 | +------------------+-------+------+ -Flink SQL> SELECT L.Id as L, R.Id as R, L.window_start, L.window_end +Flink SQL> SELECT L.Num as L_Num, L.Id as L_Id, R.Num as R_Num, R.Id as R_Id, L.window_start, L.window_end FROM ( SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) ) L @@ -94,15 +94,15 @@ Flink SQL> SELECT L.Id as L, R.Id as R, L.window_start, L.window_end SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) ) R ON L.Num = R.Num AND L.window_start = R.window_start AND L.window_end = R.window_end; -+--------+--------+---------------------+---------------------+ -| L | R | window_start | window_end | -+--------+--------+---------------------+---------------------+ -| L1 | null | 2020-04-15 12:00 | 2020-04-15 12:05 | -| null | R2 | 2020-04-15 12:00 | 2020-04-15 12:05 | -| L3 | R3 | 2020-04-15 12:00 | 2020-04-15 12:05 | -| L2 | null | 2020-04-15 12:05 | 2020-04-15 12:10 | -| null | R4 | 2020-04-15 12:05 | 2020-04-15 12:10 | -+--------+--------+---------------------+---------------------+ ++--------+--------+--------+--------+---------------------+---------------------+ +| L_Num | L_Id | R_Num | R_Id | window_start | window_end | ++--------+--------+--------+--------+---------------------+---------------------+ +| 1 | L1 | null | null | 2020-04-15 12:00 | 2020-04-15 12:05 | +| null | null | 2 | R2 | 2020-04-15 12:00 | 2020-04-15 12:05 | +| 3 | L3 | 3 | R3 | 2020-04-15 12:00 | 2020-04-15 12:05 | +| 2 | L2 | null | null | 2020-04-15 12:05 | 2020-04-15 12:10 | +| null | null | 4 | R4 | 2020-04-15 12:05 | 2020-04-15 12:10 | ++--------+--------+--------+--------+---------------------+---------------------+ ``` *Note: in order to better understand the behavior of windowing, we simplify the displaying of timestamp values to not show the trailing zeros, e.g. `2020-04-15 08:05` should be displayed as `2020-04-15 08:05:00.000` in Flink SQL Client if the type is `TIMESTAMP(3)`.* diff --git a/docs/content/docs/dev/table/sql/queries/window-join.md b/docs/content/docs/dev/table/sql/queries/window-join.md index 3ad65a6fc0265..8ca716fd9f71c 100644 --- a/docs/content/docs/dev/table/sql/queries/window-join.md +++ b/docs/content/docs/dev/table/sql/queries/window-join.md @@ -33,7 +33,11 @@ Usually, Window join is used with [Windowing TVF]({{< ref "docs/dev/table/sql/qu Currently, Window join requires the join on condition contains window starts equality of input tables and window ends equality of input tables. -The following shows the syntax of the Window join statement: +Window join supports INNER/LEFT/RIGHT/FULL OUTER/ANTI/SEMI JOIN. + +## INNER/LEFT/RIGHT/FULL OUTER + +The following shows the syntax of the INNER/LEFT/RIGHT/FULL OUTER Window join statement. ```sql SELECT ... @@ -41,10 +45,6 @@ FROM L [LEFT|RIGHT|FULL OUTER] JOIN R -- L and R are relations applied windowing ON L.window_start = R.window_start AND L.window_end = R.window_end AND ... ``` -Window join supports INNER/LEFT/RIGHT/FULL OUTER/ANTI/SEMI JOIN. - -## INNER/LEFT/RIGHT/FULL OUTER - The syntax of INNER/LEFT/RIGHT/FULL OUTER WINDOW JOIN are very similar with each other, we only give an example for FULL OUTER JOIN here. When performing a window join, all elements with a common key and a common tumbling window are joined together. We only give an example for a Window join which works on a Tumble Window TVF. By scoping the region of time for the join into fixed five-minute intervals, we chopped our datasets into two distinct windows of time: [12:00, 12:05) and [12:05, 12:10). The L2 and R2 rows could not join together because they fell into separate windows. @@ -86,7 +86,7 @@ Flink SQL> SELECT * FROM RightTable; | 2020-04-15 12:05 | 4 | R4 | +------------------+-------+------+ -Flink SQL> SELECT L.Id as L, R.Id as R, L.window_start, L.window_end +Flink SQL> SELECT L.Num as L_Num, L.Id as L_Id, R.Num as R_Num, R.Id as R_Id, L.window_start, L.window_end FROM ( SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) ) L @@ -94,15 +94,15 @@ Flink SQL> SELECT L.Id as L, R.Id as R, L.window_start, L.window_end SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) ) R ON L.Num = R.Num AND L.window_start = R.window_start AND L.window_end = R.window_end; -+--------+--------+---------------------+---------------------+ -| L | R | window_start | window_end | -+--------+--------+---------------------+---------------------+ -| L1 | null | 2020-04-15 12:00 | 2020-04-15 12:05 | -| null | R2 | 2020-04-15 12:00 | 2020-04-15 12:05 | -| L3 | R3 | 2020-04-15 12:00 | 2020-04-15 12:05 | -| L2 | null | 2020-04-15 12:05 | 2020-04-15 12:10 | -| null | R4 | 2020-04-15 12:05 | 2020-04-15 12:10 | -+--------+--------+---------------------+---------------------+ ++--------+--------+--------+--------+---------------------+---------------------+ +| L_Num | L_Id | R_Num | R_Id | window_start | window_end | ++--------+--------+--------+--------+---------------------+---------------------+ +| 1 | L1 | null | null | 2020-04-15 12:00 | 2020-04-15 12:05 | +| null | null | 2 | R2 | 2020-04-15 12:00 | 2020-04-15 12:05 | +| 3 | L3 | 3 | R3 | 2020-04-15 12:00 | 2020-04-15 12:05 | +| 2 | L2 | null | null | 2020-04-15 12:05 | 2020-04-15 12:10 | +| null | null | 4 | R4 | 2020-04-15 12:05 | 2020-04-15 12:10 | ++--------+--------+--------+--------+---------------------+---------------------+ ``` *Note: in order to better understand the behavior of windowing, we simplify the displaying of timestamp values to not show the trailing zeros, e.g. `2020-04-15 08:05` should be displayed as `2020-04-15 08:05:00.000` in Flink SQL Client if the type is `TIMESTAMP(3)`.* From f335b3ac61e9b8417458e238796f822e35910c4c Mon Sep 17 00:00:00 2001 From: Jing Date: Sun, 29 Aug 2021 14:13:44 +0800 Subject: [PATCH 3/6] Minor update --- .../docs/dev/table/sql/queries/window-join.md | 32 +++++++++---------- .../docs/dev/table/sql/queries/window-join.md | 32 +++++++++---------- 2 files changed, 32 insertions(+), 32 deletions(-) diff --git a/docs/content.zh/docs/dev/table/sql/queries/window-join.md b/docs/content.zh/docs/dev/table/sql/queries/window-join.md index 795b58a51843f..3784d2a2d0807 100644 --- a/docs/content.zh/docs/dev/table/sql/queries/window-join.md +++ b/docs/content.zh/docs/dev/table/sql/queries/window-join.md @@ -22,22 +22,22 @@ specific language governing permissions and limitations under the License. --> -# Window JOIN +# Window Join {{< label Streaming >}} -A window join adds the dimension of time into the join criteria themselves. In doing so, the window join joins the elements of two streams that share a common key and lie in the same window. The semantic of window join is same to the [DataStream window join]({{< ref "docs/dev/datastream/operators/joining" >}}#Window Join) +A window join adds the dimension of time into the join criteria themselves. In doing so, the window join joins the elements of two streams that share a common key and lie in the same window. The semantic of window join is same to the [DataStream window join]({{< ref "docs/dev/datastream/operators/joining" >}}#window-join) For streaming queries, unlike other joins on continuous tables, window join does not emit intermediate results but only emits final results at the end of the window. Moreover, window join purge all intermediate state when no longer needed. -Usually, Window join is used with [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}). Besides, Window join could follow after other operations based on [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}), such as [Window Aggregation]({{< ref "docs/dev/table/sql/queries/window-agg" >}}), [Window TopN]({{< ref "docs/dev/table/sql/queries/window-topn">}}) and [Window Join]({{< ref "docs/dev/table/sql/queries/window-join">}}). +Usually, Window Join is used with [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}). Besides, Window Join could follow after other operations based on [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}), such as [Window Aggregation]({{< ref "docs/dev/table/sql/queries/window-agg" >}}), [Window TopN]({{< ref "docs/dev/table/sql/queries/window-topn">}}) and [Window Join]({{< ref "docs/dev/table/sql/queries/window-join">}}). -Currently, Window join requires the join on condition contains window starts equality of input tables and window ends equality of input tables. +Currently, Window Join requires the join on condition contains window starts equality of input tables and window ends equality of input tables. -Window join supports INNER/LEFT/RIGHT/FULL OUTER/ANTI/SEMI JOIN. +Window Join supports INNER/LEFT/RIGHT/FULL OUTER/ANTI/SEMI JOIN. ## INNER/LEFT/RIGHT/FULL OUTER -The following shows the syntax of the INNER/LEFT/RIGHT/FULL OUTER Window join statement. +The following shows the syntax of the INNER/LEFT/RIGHT/FULL OUTER Window Join statement. ```sql SELECT ... @@ -46,7 +46,7 @@ ON L.window_start = R.window_start AND L.window_end = R.window_end AND ... ``` The syntax of INNER/LEFT/RIGHT/FULL OUTER WINDOW JOIN are very similar with each other, we only give an example for FULL OUTER JOIN here. -When performing a window join, all elements with a common key and a common tumbling window are joined together. We only give an example for a Window join which works on a Tumble Window TVF. +When performing a window join, all elements with a common key and a common tumbling window are joined together. We only give an example for a Window Join which works on a Tumble Window TVF. By scoping the region of time for the join into fixed five-minute intervals, we chopped our datasets into two distinct windows of time: [12:00, 12:05) and [12:05, 12:10). The L2 and R2 rows could not join together because they fell into separate windows. ```sql @@ -54,8 +54,8 @@ Flink SQL> desc LeftTable; +-------------+------------------------+------+-----+--------+---------------------------------+ | name | type | null | key | extras | watermark | +-------------+------------------------+------+-----+--------+---------------------------------+ -| `Time` | TIMESTAMP(3) *ROWTIME* | true | | | `Time` - INTERVAL '1' SECOND | -| Num | Int | true | | | | +| Time | TIMESTAMP(3) *ROWTIME* | true | | | `Time` - INTERVAL '1' SECOND | +| Num | INT | true | | | | | Id | STRING | true | | | | +-------------+------------------------+------+-----+--------+---------------------------------+ @@ -72,8 +72,8 @@ Flink SQL> desc RightTable; +-------------+------------------------+------+-----+--------+---------------------------------+ | name | type | null | key | extras | watermark | +-------------+------------------------+------+-----+--------+---------------------------------+ -| `Time` | TIMESTAMP(3) *ROWTIME* | true | | | `Time` - INTERVAL '1' SECOND | -| Num | Int | true | | | | +| Time | TIMESTAMP(3) *ROWTIME* | true | | | `Time` - INTERVAL '1' SECOND | +| Num | INT | true | | | | | Id | STRING | true | | | | +-------------+------------------------+------+-----+--------+---------------------------------+ @@ -88,10 +88,10 @@ Flink SQL> SELECT * FROM RightTable; Flink SQL> SELECT L.Num as L_Num, L.Id as L_Id, R.Num as R_Num, R.Id as R_Id, L.window_start, L.window_end FROM ( - SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(`Time`), INTERVAL '5' MINUTES)) ) L FULL JOIN ( - SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(`Time`), INTERVAL '5' MINUTES)) ) R ON L.Num = R.Num AND L.window_start = R.window_start AND L.window_end = R.window_end; +--------+--------+--------+--------+---------------------+---------------------+ @@ -143,7 +143,7 @@ Flink SQL> SELECT * ## ANTI -Anti Window Joins are the obverse of the Inner Window join: they contain all of the unjoined rows within each common window. +###### Anti Window Joins are the obverse of the Inner Window Join: they contain all of the unjoined rows within each common window. ```sql Flink SQL> SELECT * @@ -186,7 +186,7 @@ Currently, The window join requires the join on condition contains window starts ### Limitation on windowing TVFs of inputs Currently, the windowing TVFs must be the same of left and right inputs. This can be extended in the future, for example, tumbling windows join sliding windows with the same window size. -### Limitation on Window join which follows after Windowing TVFs directly -Currently, if Window join follows after [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}), the [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}) has to be with Tumble Windows, Hop Windows or Cumulate Windows instead of Session windows. +### Limitation on Window Join which follows after Windowing TVFs directly +Currently, if Window Join follows after [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}), the [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}) has to be with Tumble Windows, Hop Windows or Cumulate Windows instead of Session windows. {{< top >}} diff --git a/docs/content/docs/dev/table/sql/queries/window-join.md b/docs/content/docs/dev/table/sql/queries/window-join.md index 8ca716fd9f71c..c46ce978aaee7 100644 --- a/docs/content/docs/dev/table/sql/queries/window-join.md +++ b/docs/content/docs/dev/table/sql/queries/window-join.md @@ -22,22 +22,22 @@ specific language governing permissions and limitations under the License. --> -# Window JOIN +# Window Join {{< label Streaming >}} -A window join adds the dimension of time into the join criteria themselves. In doing so, the window join joins the elements of two streams that share a common key and lie in the same window. The semantic of window join is same to the [DataStream window join]({{< ref "docs/dev/datastream/operators/joining" >}}#Window Join) +A window join adds the dimension of time into the join criteria themselves. In doing so, the window join joins the elements of two streams that share a common key and lie in the same window. The semantic of window join is same to the [DataStream window join]({{< ref "docs/dev/datastream/operators/joining" >}}#window-join) For streaming queries, unlike other joins on continuous tables, window join does not emit intermediate results but only emits final results at the end of the window. Moreover, window join purge all intermediate state when no longer needed. -Usually, Window join is used with [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}). Besides, Window join could follow after other operations based on [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}), such as [Window Aggregation]({{< ref "docs/dev/table/sql/queries/window-agg" >}}), [Window TopN]({{< ref "docs/dev/table/sql/queries/window-topn">}}) and [Window Join]({{< ref "docs/dev/table/sql/queries/window-join">}}). +Usually, Window Join is used with [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}). Besides, Window Join could follow after other operations based on [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}), such as [Window Aggregation]({{< ref "docs/dev/table/sql/queries/window-agg" >}}), [Window TopN]({{< ref "docs/dev/table/sql/queries/window-topn">}}) and [Window Join]({{< ref "docs/dev/table/sql/queries/window-join">}}). -Currently, Window join requires the join on condition contains window starts equality of input tables and window ends equality of input tables. +Currently, Window Join requires the join on condition contains window starts equality of input tables and window ends equality of input tables. -Window join supports INNER/LEFT/RIGHT/FULL OUTER/ANTI/SEMI JOIN. +Window Join supports INNER/LEFT/RIGHT/FULL OUTER/ANTI/SEMI JOIN. ## INNER/LEFT/RIGHT/FULL OUTER -The following shows the syntax of the INNER/LEFT/RIGHT/FULL OUTER Window join statement. +The following shows the syntax of the INNER/LEFT/RIGHT/FULL OUTER Window Join statement. ```sql SELECT ... @@ -46,7 +46,7 @@ ON L.window_start = R.window_start AND L.window_end = R.window_end AND ... ``` The syntax of INNER/LEFT/RIGHT/FULL OUTER WINDOW JOIN are very similar with each other, we only give an example for FULL OUTER JOIN here. -When performing a window join, all elements with a common key and a common tumbling window are joined together. We only give an example for a Window join which works on a Tumble Window TVF. +When performing a window join, all elements with a common key and a common tumbling window are joined together. We only give an example for a Window Join which works on a Tumble Window TVF. By scoping the region of time for the join into fixed five-minute intervals, we chopped our datasets into two distinct windows of time: [12:00, 12:05) and [12:05, 12:10). The L2 and R2 rows could not join together because they fell into separate windows. ```sql @@ -54,8 +54,8 @@ Flink SQL> desc LeftTable; +-------------+------------------------+------+-----+--------+---------------------------------+ | name | type | null | key | extras | watermark | +-------------+------------------------+------+-----+--------+---------------------------------+ -| `Time` | TIMESTAMP(3) *ROWTIME* | true | | | `Time` - INTERVAL '1' SECOND | -| Num | Int | true | | | | +| Time | TIMESTAMP(3) *ROWTIME* | true | | | `Time` - INTERVAL '1' SECOND | +| Num | INT | true | | | | | Id | STRING | true | | | | +-------------+------------------------+------+-----+--------+---------------------------------+ @@ -72,8 +72,8 @@ Flink SQL> desc RightTable; +-------------+------------------------+------+-----+--------+---------------------------------+ | name | type | null | key | extras | watermark | +-------------+------------------------+------+-----+--------+---------------------------------+ -| `Time` | TIMESTAMP(3) *ROWTIME* | true | | | `Time` - INTERVAL '1' SECOND | -| Num | Int | true | | | | +| Time | TIMESTAMP(3) *ROWTIME* | true | | | `Time` - INTERVAL '1' SECOND | +| Num | INT | true | | | | | Id | STRING | true | | | | +-------------+------------------------+------+-----+--------+---------------------------------+ @@ -143,7 +143,7 @@ Flink SQL> SELECT * ## ANTI -Anti Window Joins are the obverse of the Inner Window join: they contain all of the unjoined rows within each common window. +Anti Window Joins are the obverse of the Inner Window Join: they contain all of the unjoined rows within each common window. ```sql Flink SQL> SELECT * @@ -162,10 +162,10 @@ Flink SQL> SELECT * Flink SQL> SELECT * FROM ( - SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + SELECT * FROM TABLE(TUMBLE(TABLE LeftTable, DESCRIPTOR(`Time`), INTERVAL '5' MINUTES)) ) L WHERE NOT EXISTS ( SELECT * FROM ( - SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(row_time), INTERVAL '5' MINUTES)) + SELECT * FROM TABLE(TUMBLE(TABLE RightTable, DESCRIPTOR(`Time`), INTERVAL '5' MINUTES)) ) R WHERE L.Num = R.Num AND L.window_start = R.window_start AND L.window_end = R.window_end); +------------------+-------+------+------------------+------------------+-------------------------+ | `Time` | Num | Id | window_start | window_end | window_time | @@ -186,7 +186,7 @@ Currently, The window join requires the join on condition contains window starts ### Limitation on windowing TVFs of inputs Currently, the windowing TVFs must be the same of left and right inputs. This can be extended in the future, for example, tumbling windows join sliding windows with the same window size. -### Limitation on Window join which follows after Windowing TVFs directly -Currently, if Window join follows after [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}), the [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}) has to be with Tumble Windows, Hop Windows or Cumulate Windows instead of Session windows. +### Limitation on Window Join which follows after Windowing TVFs directly +Currently, if Window Join follows after [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}), the [Windowing TVF]({{< ref "docs/dev/table/sql/queries/window-tvf" >}}) has to be with Tumble Windows, Hop Windows or Cumulate Windows instead of Session windows. {{< top >}} From 717cc232df32c0a19b2026b7246af7b307c14dc7 Mon Sep 17 00:00:00 2001 From: Jing Date: Sun, 29 Aug 2021 14:24:51 +0800 Subject: [PATCH 4/6] Update window join weight --- docs/content.zh/docs/dev/table/sql/queries/window-join.md | 2 +- docs/content/docs/dev/table/sql/queries/window-join.md | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/docs/content.zh/docs/dev/table/sql/queries/window-join.md b/docs/content.zh/docs/dev/table/sql/queries/window-join.md index 3784d2a2d0807..0a775963a0e6b 100644 --- a/docs/content.zh/docs/dev/table/sql/queries/window-join.md +++ b/docs/content.zh/docs/dev/table/sql/queries/window-join.md @@ -1,6 +1,6 @@ --- title: "窗口关联" -weight: 15 +weight: 10 type: docs ---