mirror of
https://github.com/ClickHouse/ClickHouse.git
synced 2024-11-27 18:12:02 +00:00
125 lines
4.4 KiB
Markdown
125 lines
4.4 KiB
Markdown
---
|
|
slug: /en/engines/table-engines/mergetree-family/aggregatingmergetree
|
|
sidebar_position: 60
|
|
sidebar_label: AggregatingMergeTree
|
|
---
|
|
|
|
# AggregatingMergeTree
|
|
|
|
The engine inherits from [MergeTree](../../../engines/table-engines/mergetree-family/mergetree.md#table_engines-mergetree), altering the logic for data parts merging. ClickHouse replaces all rows with the same primary key (or more accurately, with the same [sorting key](../../../engines/table-engines/mergetree-family/mergetree.md)) with a single row (within a one data part) that stores a combination of states of aggregate functions.
|
|
|
|
You can use `AggregatingMergeTree` tables for incremental data aggregation, including for aggregated materialized views.
|
|
|
|
The engine processes all columns with the following types:
|
|
|
|
## [AggregateFunction](../../../sql-reference/data-types/aggregatefunction.md)
|
|
## [SimpleAggregateFunction](../../../sql-reference/data-types/simpleaggregatefunction.md)
|
|
|
|
It is appropriate to use `AggregatingMergeTree` if it reduces the number of rows by orders.
|
|
|
|
## Creating a Table {#creating-a-table}
|
|
|
|
``` sql
|
|
CREATE TABLE [IF NOT EXISTS] [db.]table_name [ON CLUSTER cluster]
|
|
(
|
|
name1 [type1] [DEFAULT|MATERIALIZED|ALIAS expr1],
|
|
name2 [type2] [DEFAULT|MATERIALIZED|ALIAS expr2],
|
|
...
|
|
) ENGINE = AggregatingMergeTree()
|
|
[PARTITION BY expr]
|
|
[ORDER BY expr]
|
|
[SAMPLE BY expr]
|
|
[TTL expr]
|
|
[SETTINGS name=value, ...]
|
|
```
|
|
|
|
For a description of request parameters, see [request description](../../../sql-reference/statements/create/table.md).
|
|
|
|
**Query clauses**
|
|
|
|
When creating an `AggregatingMergeTree` table the same [clauses](../../../engines/table-engines/mergetree-family/mergetree.md) are required, as when creating a `MergeTree` table.
|
|
|
|
<details markdown="1">
|
|
|
|
<summary>Deprecated Method for Creating a Table</summary>
|
|
|
|
:::warning
|
|
Do not use this method in new projects and, if possible, switch the old projects to the method described above.
|
|
:::
|
|
|
|
``` sql
|
|
CREATE TABLE [IF NOT EXISTS] [db.]table_name [ON CLUSTER cluster]
|
|
(
|
|
name1 [type1] [DEFAULT|MATERIALIZED|ALIAS expr1],
|
|
name2 [type2] [DEFAULT|MATERIALIZED|ALIAS expr2],
|
|
...
|
|
) ENGINE [=] AggregatingMergeTree(date-column [, sampling_expression], (primary, key), index_granularity)
|
|
```
|
|
|
|
All of the parameters have the same meaning as in `MergeTree`.
|
|
</details>
|
|
|
|
## SELECT and INSERT {#select-and-insert}
|
|
|
|
To insert data, use [INSERT SELECT](../../../sql-reference/statements/insert-into.md) query with aggregate -State- functions.
|
|
When selecting data from `AggregatingMergeTree` table, use `GROUP BY` clause and the same aggregate functions as when inserting data, but using `-Merge` suffix.
|
|
|
|
In the results of `SELECT` query, the values of `AggregateFunction` type have implementation-specific binary representation for all of the ClickHouse output formats. If dump data into, for example, `TabSeparated` format with `SELECT` query then this dump can be loaded back using `INSERT` query.
|
|
|
|
## Example of an Aggregated Materialized View {#example-of-an-aggregated-materialized-view}
|
|
|
|
We will create the table `test.visits` that contain the raw data:
|
|
|
|
``` sql
|
|
CREATE TABLE test.visits
|
|
(
|
|
StartDate DateTime64 NOT NULL,
|
|
CounterID UInt64,
|
|
Sign Nullable(Int32),
|
|
UserID Nullable(Int32)
|
|
) ENGINE = MergeTree ORDER BY (StartDate, CounterID);
|
|
```
|
|
|
|
`AggregatingMergeTree` materialized view that watches the `test.visits` table, and use the `AggregateFunction` type:
|
|
|
|
``` sql
|
|
CREATE MATERIALIZED VIEW test.mv_visits
|
|
(
|
|
StartDate DateTime64 NOT NULL,
|
|
CounterID UInt64,
|
|
Visits AggregateFunction(sum, Nullable(Int32)),
|
|
Users AggregateFunction(uniq, Nullable(Int32))
|
|
)
|
|
ENGINE = AggregatingMergeTree() ORDER BY (StartDate, CounterID)
|
|
AS SELECT
|
|
StartDate,
|
|
CounterID,
|
|
sumState(Sign) AS Visits,
|
|
uniqState(UserID) AS Users
|
|
FROM test.visits
|
|
GROUP BY StartDate, CounterID;
|
|
```
|
|
|
|
Inserting data into the `test.visits` table.
|
|
|
|
``` sql
|
|
INSERT INTO test.visits (StartDate, CounterID, Sign, UserID)
|
|
VALUES (1667446031, 1, 3, 4)
|
|
INSERT INTO test.visits (StartDate, CounterID, Sign, UserID)
|
|
VALUES (1667446031, 1, 6, 3)
|
|
```
|
|
|
|
The data are inserted in both the table and the materialized view `test.mv_visits`.
|
|
|
|
To get the aggregated data, we need to execute a query such as `SELECT ... GROUP BY ...` from the materialized view `test.mv_visits`:
|
|
|
|
``` sql
|
|
SELECT
|
|
StartDate,
|
|
sumMerge(Visits) AS Visits,
|
|
uniqMerge(Users) AS Users
|
|
FROM test.mv_visits
|
|
GROUP BY StartDate
|
|
ORDER BY StartDate;
|
|
```
|