From 1cf68baad70ee0dccf2f0139c2d493f9a6526537 Mon Sep 17 00:00:00 2001 From: vdimir Date: Thu, 24 Aug 2023 09:28:02 +0000 Subject: [PATCH] Add NULL values in JOIN keys section to join doc --- .../sql-reference/statements/select/join.md | 55 +++++++++++++++++++ 1 file changed, 55 insertions(+) diff --git a/docs/en/sql-reference/statements/select/join.md b/docs/en/sql-reference/statements/select/join.md index 7971b3ba275..38922e964b8 100644 --- a/docs/en/sql-reference/statements/select/join.md +++ b/docs/en/sql-reference/statements/select/join.md @@ -163,6 +163,61 @@ Result: │ 4 │ -4 │ 4 │ └───┴────┴─────┘ ``` + +## NULL values in JOIN keys + +The NULL is not equal to any value, including itself. It means that if a JOIN key has a NULL value in one table, it won't match a NULL value in the other table. + +**Example** + +Table `A`: + +``` +┌───id─┬─name────┐ +│ 1 │ Alice │ +│ 2 │ Bob │ +│ ᴺᵁᴸᴸ │ Charlie │ +└──────┴─────────┘ +``` + +Table `B`: + +``` +┌───id─┬─score─┐ +│ 1 │ 90 │ +│ 3 │ 85 │ +│ ᴺᵁᴸᴸ │ 88 │ +└──────┴───────┘ +``` + +```sql +SELECT A.name, B.score FROM A LEFT JOIN B ON A.id = B.id +``` + +``` +┌─name────┬─score─┐ +│ Alice │ 90 │ +│ Bob │ 0 │ +│ Charlie │ 0 │ +└─────────┴───────┘ +``` + +Notice that the row with `Charlie` from table `A` and the row with score 88 from table `B` are not in the result because of the NULL value in the JOIN key. + +In case you want to match NULL values, use the `isNotDistinctFrom` function to compare the JOIN keys. + +```sql +SELECT A.name, B.score FROM A LEFT JOIN B ON isNotDistinctFrom(A.id, B.id) +``` + +``` +┌─name────┬─score─┐ +│ Alice │ 90 │ +│ Bob │ 0 │ +│ Charlie │ 88 │ +└─────────┴───────┘ +``` + ## ASOF JOIN Usage `ASOF JOIN` is useful when you need to join records that have no exact match.