ClickHouse/docs/en/operations/table_engines/join.md

95 lines
3.7 KiB
Markdown
Raw Normal View History

# Join
2017-04-03 19:49:50 +00:00
Prepared data structure for using in [JOIN](../../query_language/select.md#select-join) operations.
## Creating a Table
```
CREATE TABLE [IF NOT EXISTS] [db.]table_name [ON CLUSTER cluster]
(
name1 [type1] [DEFAULT|MATERIALIZED|ALIAS expr1] [TTL expr1],
name2 [type2] [DEFAULT|MATERIALIZED|ALIAS expr2] [TTL expr2],
) ENGINE = Join(join_strictness, join_type, k1[, k2, ...])
```
See the detailed description of [CREATE TABLE](../../query_language/create.md#create-table-query) query.
**Engine Parameters**
- `join_strictness` [JOIN strictness](../../query_language/select.md#select-join-strictness).
- `join_type` [JOIN type](../../query_language/select.md#select-join-types).
- `k1[, k2, ...]` Key columns from the `USING` clause that the `JOIN` operation is made with.
Set the parameters `join_strictness` and `join_type` without quotes, for example, `Join(ANY, LEFT, col1)`. They must match the `JOIN` operation that the table will be used for. If parameters don't match, ClickHouse doesn't throw an exception and may return incorrect data.
## Table Usage
### Example
Creating the left-side table:
```sql
CREATE TABLE id_val(`id` UInt32, `val` UInt32) ENGINE = TinyLog;
INSERT INTO id_val VALUES (1,11)(2,12)(3,13);
```
CLICKHOUSE-2720: progress on website (#865) * update presentations * CLICKHOUSE-2936: redirect from clickhouse.yandex.ru and clickhouse.yandex.com * update submodule * lost files * CLICKHOUSE-2981: prefer sphinx docs over original reference * CLICKHOUSE-2981: docs styles more similar to main website + add flags to switch language links * update presentations * Less confusing directory structure (docs -> doc/reference/) * Minify sphinx docs too * Website release script: fail fast + pass docker hash on deploy * Do not underline links in docs * shorter * cleanup docker images * tune nginx config * CLICKHOUSE-3043: get rid of habrastorage links * Lost translation * CLICKHOUSE-2936: temporary client-side redirect * behaves weird in test * put redirect back * CLICKHOUSE-3047: copy docs txts to public too * move to proper file * remove old pages to avoid confusion * Remove reference redirect warning for now * Refresh README.md * Yellow buttons in docs * Use svg flags instead of unicode ones in docs * fix test website instance * Put flags to separate files * wrong flag * Copy Yandex.Metrica introduction from main page to docs * Yet another home page structure change, couple new blocks (CLICKHOUSE-3045) * Update Contacts section * CLICKHOUSE-2849: more detailed legal information * CLICKHOUSE-2978 preparation - split by files * More changes in Contacts block * Tune texts on index page * update presentations * One more benchmark * Add usage sections to index page, adapted from slides * Get the roadmap started, based on slides from last ClickHouse Meetup * CLICKHOUSE-2977: some rendering tuning * Get rid of excessive section in the end of getting started * Make headers linkable * CLICKHOUSE-2981: links to editing reference - https://github.com/yandex/ClickHouse/issues/849 * CLICKHOUSE-2981: fix mobile styles in docs * Ban crawling of duplicating docs * Open some external links in new tab * Ban old docs too * Lots of trivial fixes in english docs * Lots of trivial fixes in russian docs * Remove getting started copies in markdown * Add Yandex.Webmaster * Fix some sphinx warnings * More warnings fixed in english docs * More sphinx warnings fixed * Add code-block:: text * More code-block:: text * These headers look not that well * Better switch between documentation languages * merge use_case.rst into ya_metrika_task.rst * Edit the agg_functions.rst texts * Add lost empty lines
2017-06-13 04:15:47 +00:00
Creating the right-side `Join` table:
2017-04-03 19:49:50 +00:00
```sql
CREATE TABLE id_val_join(`id` UInt32, `val` UInt8) ENGINE = Join(ANY, LEFT, id);
INSERT INTO id_val_join VALUES (1,21)(1,22)(3,23)
```
2017-04-03 19:49:50 +00:00
Joining the tables:
```sql
SELECT * FROM id_val ANY LEFT JOIN id_val_join USING (id) SETTINGS join_use_nulls = 1
```
```text
┌─id─┬─val─┬─id_val_join.val─┐
│ 1 │ 11 │ 21 │
│ 2 │ 12 │ ᴺᵁᴸᴸ │
│ 3 │ 13 │ 23 │
└────┴─────┴─────────────────┘
```
2017-04-03 19:49:50 +00:00
Retrieving the data from the `Join` table, specifying the join key value:
```sql
SELECT joinGet('id_val_join', 'val', toUInt32(1))
```
```text
┌─joinGet('id_val_join', 'val', toUInt32(1))─┐
│ 21 │
└────────────────────────────────────────────┘
```
### Selecting and Inserting Data
You can use `INSERT` to add data to the table. For the `ANY` strictness, data for duplicated keys are ignored. For the `ALL` strictness, all rows are kept.
You cannot perform the `SELECT` query directly from the table. Use one of the following ways:
- Place the table at the right side in a `JOIN` clause.
- Call the [joinGet](../../query_language/functions/other_functions.md#other_functions-joinget) function, which allows to extract data from the table as from a dictionary.
### Limitations and Settings
When creating a table, the following settings are applied:
- [join_use_nulls](../settings/settings.md#settings-join_use_nulls)
- [max_rows_in_join](../settings/query_complexity.md#settings-max_rows_in_join)
- [max_bytes_in_join](../settings/query_complexity.md#settings-max_bytes_in_join)
- [join_overflow_mode](../settings/query_complexity.md#settings-join_overflow_mode)
- [join_any_take_last_row](../settings/settings.md#settings-join_any_take_last_row)
The table can't be used in `GLOBAL JOIN` operations.
## Data Storage
Data for the `Join` tables is always located in RAM. When inserting rows into the table, ClickHouse writes the data blocks to the directory on disk to be able to restore them on server restart.
At the abnormal server restart, the block of data on the disk might be lost or damaged. In this case, you may need to manually delete the file with damaged data.
[Original article](https://clickhouse.yandex/docs/en/operations/table_engines/join/) <!--hide-->