diff --git a/docs/en/sql-reference/functions/other-functions.md b/docs/en/sql-reference/functions/other-functions.md index 79bffe00d01..012b0db96b5 100644 --- a/docs/en/sql-reference/functions/other-functions.md +++ b/docs/en/sql-reference/functions/other-functions.md @@ -2449,11 +2449,11 @@ As you can see, `runningAccumulate` merges states for each group of rows separat ## joinGet -The function lets you extract data from the table the same way as from a [dictionary](../../sql-reference/dictionaries/index.md). - -Gets the data from [Join](../../engines/table-engines/special/join.md#creating-a-table) tables using the specified join key. +The function lets you extract data from the table the same way as from a [dictionary](../../sql-reference/dictionaries/index.md). Gets the data from [Join](../../engines/table-engines/special/join.md#creating-a-table) tables using the specified join key. +:::note Only supports tables created with the `ENGINE = Join(ANY, LEFT, )` statement. +::: **Syntax** @@ -2463,26 +2463,32 @@ joinGet(join_storage_table_name, `value_column`, join_keys) **Arguments** -- `join_storage_table_name` — an [identifier](../../sql-reference/syntax.md#syntax-identifiers) indicating where the search is performed. The identifier is searched in the default database (see setting `default_database` in the config file). To override the default database, use `USE db_name` or specify the database and the table through the separator `db_name.db_table` as in the example. +- `join_storage_table_name` — an [identifier](../../sql-reference/syntax.md#syntax-identifiers) indicating where the search is performed. - `value_column` — name of the column of the table that contains required data. - `join_keys` — list of keys. +:::note +The identifier is searched for in the default database (see setting `default_database` in the config file). To override the default database, use `USE db_name` or specify the database and the table through the separator `db_name.db_table` as in the example. +::: + **Returned value** -Returns a list of values corresponded to list of keys. - -If certain does not exist in source table then `0` or `null` will be returned based on [join_use_nulls](../../operations/settings/settings.md#join_use_nulls) setting. +- Returns a list of values corresponded to the list of keys. +:::note +If a certain key does not exist in source table then `0` or `null` will be returned based on [join_use_nulls](../../operations/settings/settings.md#join_use_nulls) setting during table creation. More info about `join_use_nulls` in [Join operation](../../engines/table-engines/special/join.md). +::: **Example** Input table: ```sql -CREATE DATABASE db_test -CREATE TABLE db_test.id_val(`id` UInt32, `val` UInt32) ENGINE = Join(ANY, LEFT, id) SETTINGS join_use_nulls = 1 -INSERT INTO db_test.id_val VALUES (1,11)(2,12)(4,13) +CREATE DATABASE db_test; +CREATE TABLE db_test.id_val(`id` UInt32, `val` UInt32) ENGINE = Join(ANY, LEFT, id); +INSERT INTO db_test.id_val VALUES (1, 11)(2, 12)(4, 13); +SELECT * FROM db_test.id_val; ``` ```text @@ -2496,18 +2502,116 @@ INSERT INTO db_test.id_val VALUES (1,11)(2,12)(4,13) Query: ```sql -SELECT joinGet(db_test.id_val, 'val', toUInt32(number)) from numbers(4) SETTINGS join_use_nulls = 1 +SELECT number, joinGet(db_test.id_val, 'val', toUInt32(number)) from numbers(4); ``` Result: ```text -┌─joinGet(db_test.id_val, 'val', toUInt32(number))─┐ -│ 0 │ -│ 11 │ -│ 12 │ -│ 0 │ -└──────────────────────────────────────────────────┘ + ┌─number─┬─joinGet('db_test.id_val', 'val', toUInt32(number))─┐ +1. │ 0 │ 0 │ +2. │ 1 │ 11 │ +3. │ 2 │ 12 │ +4. │ 3 │ 0 │ + └────────┴────────────────────────────────────────────────────┘ +``` + +Setting `join_use_nulls` can be used during table creation to change the behaviour of what gets returned if no key exists in the source table. + +```sql +CREATE DATABASE db_test; +CREATE TABLE db_test.id_val_nulls(`id` UInt32, `val` UInt32) ENGINE = Join(ANY, LEFT, id) SETTINGS join_use_nulls=1; +INSERT INTO db_test.id_val_nulls VALUES (1, 11)(2, 12)(4, 13); +SELECT * FROM db_test.id_val_nulls; +``` + +```text +┌─id─┬─val─┐ +│ 4 │ 13 │ +│ 2 │ 12 │ +│ 1 │ 11 │ +└────┴─────┘ +``` + +Query: + +```sql +SELECT number, joinGet(db_test.id_val_nulls, 'val', toUInt32(number)) from numbers(4); +``` + +Result: + +```text + ┌─number─┬─joinGet('db_test.id_val_nulls', 'val', toUInt32(number))─┐ +1. │ 0 │ ᴺᵁᴸᴸ │ +2. │ 1 │ 11 │ +3. │ 2 │ 12 │ +4. │ 3 │ ᴺᵁᴸᴸ │ + └────────┴──────────────────────────────────────────────────────────┘ +``` + +## joinGetOrNull + +Like [joinGet](#joinget) but returns `NULL` when the key is missing instead of returning the default value. + +**Syntax** + +```sql +joinGetOrNull(join_storage_table_name, `value_column`, join_keys) +``` + +**Arguments** + +- `join_storage_table_name` — an [identifier](../../sql-reference/syntax.md#syntax-identifiers) indicating where the search is performed. +- `value_column` — name of the column of the table that contains required data. +- `join_keys` — list of keys. + +:::note +The identifier is searched for in the default database (see setting `default_database` in the config file). To override the default database, use `USE db_name` or specify the database and the table through the separator `db_name.db_table` as in the example. +::: + +**Returned value** + +- Returns a list of values corresponded to the list of keys. + +:::note +If a certain key does not exist in source table then `NULL` is returned for that key. +::: + +**Example** + +Input table: + +```sql +CREATE DATABASE db_test; +CREATE TABLE db_test.id_val(`id` UInt32, `val` UInt32) ENGINE = Join(ANY, LEFT, id); +INSERT INTO db_test.id_val VALUES (1, 11)(2, 12)(4, 13); +SELECT * FROM db_test.id_val; +``` + +```text +┌─id─┬─val─┐ +│ 4 │ 13 │ +│ 2 │ 12 │ +│ 1 │ 11 │ +└────┴─────┘ +``` + +Query: + +```sql +SELECT number, joinGetOrNull(db_test.id_val, 'val', toUInt32(number)) from numbers(4); +``` + +Result: + +```text + ┌─number─┬─joinGetOrNull('db_test.id_val', 'val', toUInt32(number))─┐ +1. │ 0 │ ᴺᵁᴸᴸ │ +2. │ 1 │ 11 │ +3. │ 2 │ 12 │ +4. │ 3 │ ᴺᵁᴸᴸ │ + └────────┴──────────────────────────────────────────────────────────┘ ``` ## catboostEvaluate diff --git a/utils/check-style/aspell-ignore/en/aspell-dict.txt b/utils/check-style/aspell-ignore/en/aspell-dict.txt index 1a324b98ff4..e116dcd9fe4 100644 --- a/utils/check-style/aspell-ignore/en/aspell-dict.txt +++ b/utils/check-style/aspell-ignore/en/aspell-dict.txt @@ -1866,6 +1866,7 @@ jdbc jemalloc jeprof joinGet +joinGetOrNull json jsonMergePatch jsonasstring