ClickHouse/docs/en/sql-reference/statements/alter/view.md

Ignoring revisions in .git-blame-ignore-revs. Click here to bypass and see the normal blame view.

201 lines
7.6 KiB
Markdown
Raw Normal View History

---
2022-08-28 14:53:34 +00:00
slug: /en/sql-reference/statements/alter/view
sidebar_position: 50
sidebar_label: VIEW
---
# ALTER TABLE ... MODIFY QUERY Statement
You can modify `SELECT` query that was specified when a [materialized view](../create/view.md#materialized) was created with the `ALTER TABLE ... MODIFY QUERY` statement without interrupting ingestion process.
This command is created to change materialized view created with `TO [db.]name` clause. It does not change the structure of the underlying storage table and it does not change the columns' definition of the materialized view, because of this the application of this command is very limited for materialized views are created without `TO [db.]name` clause.
2023-03-19 17:01:47 +00:00
**Example with TO table**
```sql
2023-12-01 01:26:44 +00:00
CREATE TABLE events (ts DateTime, event_type String)
2023-03-19 17:01:47 +00:00
ENGINE = MergeTree ORDER BY (event_type, ts);
2023-12-01 01:26:44 +00:00
CREATE TABLE events_by_day (ts DateTime, event_type String, events_cnt UInt64)
2023-03-19 17:01:47 +00:00
ENGINE = SummingMergeTree ORDER BY (event_type, ts);
2023-12-01 01:26:44 +00:00
CREATE MATERIALIZED VIEW mv TO events_by_day AS
2023-03-19 17:01:47 +00:00
SELECT toStartOfDay(ts) ts, event_type, count() events_cnt
FROM events
2023-12-01 01:26:44 +00:00
GROUP BY ts, event_type;
2023-03-19 17:01:47 +00:00
2023-12-01 01:26:44 +00:00
INSERT INTO events
SELECT Date '2020-01-01' + interval number * 900 second,
2023-03-19 17:01:47 +00:00
['imp', 'click'][number%2+1]
FROM numbers(100);
SELECT ts, event_type, sum(events_cnt)
FROM events_by_day
GROUP BY ts, event_type
ORDER BY ts, event_type;
┌──────────────────ts─┬─event_type─┬─sum(events_cnt)─┐
│ 2020-01-01 00:00:00 │ click │ 48 │
│ 2020-01-01 00:00:00 │ imp │ 48 │
│ 2020-01-02 00:00:00 │ click │ 2 │
│ 2020-01-02 00:00:00 │ imp │ 2 │
└─────────────────────┴────────────┴─────────────────┘
2023-12-01 01:26:44 +00:00
-- Let's add the new measurment `cost`
2023-03-19 17:01:47 +00:00
-- and the new dimension `browser`.
2023-12-01 01:26:44 +00:00
ALTER TABLE events
2023-03-19 17:01:47 +00:00
ADD COLUMN browser String,
ADD COLUMN cost Float64;
2023-03-19 17:10:18 +00:00
-- Column do not have to match in a materialized view and TO
2023-03-19 17:01:47 +00:00
-- (destination table), so the next alter does not break insertion.
2023-12-01 01:26:44 +00:00
ALTER TABLE events_by_day
2023-03-19 17:01:47 +00:00
ADD COLUMN cost Float64,
ADD COLUMN browser String after event_type,
MODIFY ORDER BY (event_type, ts, browser);
2023-12-01 01:26:44 +00:00
INSERT INTO events
SELECT Date '2020-01-02' + interval number * 900 second,
2023-03-19 17:01:47 +00:00
['imp', 'click'][number%2+1],
['firefox', 'safary', 'chrome'][number%3+1],
10/(number+1)%33
FROM numbers(100);
2023-03-19 17:09:12 +00:00
-- New columns `browser` and `cost` are empty because we did not change Materialized View yet.
2023-03-19 17:01:47 +00:00
SELECT ts, event_type, browser, sum(events_cnt) events_cnt, round(sum(cost),2) cost
FROM events_by_day
GROUP BY ts, event_type, browser
ORDER BY ts, event_type;
┌──────────────────ts─┬─event_type─┬─browser─┬─events_cnt─┬─cost─┐
│ 2020-01-01 00:00:00 │ click │ │ 48 │ 0 │
│ 2020-01-01 00:00:00 │ imp │ │ 48 │ 0 │
│ 2020-01-02 00:00:00 │ click │ │ 50 │ 0 │
│ 2020-01-02 00:00:00 │ imp │ │ 50 │ 0 │
│ 2020-01-03 00:00:00 │ click │ │ 2 │ 0 │
│ 2020-01-03 00:00:00 │ imp │ │ 2 │ 0 │
└─────────────────────┴────────────┴─────────┴────────────┴──────┘
2023-12-01 01:26:44 +00:00
ALTER TABLE mv MODIFY QUERY
2023-03-19 17:01:47 +00:00
SELECT toStartOfDay(ts) ts, event_type, browser,
count() events_cnt,
sum(cost) cost
FROM events
GROUP BY ts, event_type, browser;
2023-12-01 01:26:44 +00:00
INSERT INTO events
SELECT Date '2020-01-03' + interval number * 900 second,
2023-03-19 17:01:47 +00:00
['imp', 'click'][number%2+1],
['firefox', 'safary', 'chrome'][number%3+1],
10/(number+1)%33
FROM numbers(100);
SELECT ts, event_type, browser, sum(events_cnt) events_cnt, round(sum(cost),2) cost
FROM events_by_day
GROUP BY ts, event_type, browser
ORDER BY ts, event_type;
┌──────────────────ts─┬─event_type─┬─browser─┬─events_cnt─┬──cost─┐
│ 2020-01-01 00:00:00 │ click │ │ 48 │ 0 │
│ 2020-01-01 00:00:00 │ imp │ │ 48 │ 0 │
│ 2020-01-02 00:00:00 │ click │ │ 50 │ 0 │
│ 2020-01-02 00:00:00 │ imp │ │ 50 │ 0 │
│ 2020-01-03 00:00:00 │ click │ firefox │ 16 │ 6.84 │
│ 2020-01-03 00:00:00 │ click │ │ 2 │ 0 │
│ 2020-01-03 00:00:00 │ click │ safary │ 16 │ 9.82 │
│ 2020-01-03 00:00:00 │ click │ chrome │ 16 │ 5.63 │
│ 2020-01-03 00:00:00 │ imp │ │ 2 │ 0 │
│ 2020-01-03 00:00:00 │ imp │ firefox │ 16 │ 15.14 │
│ 2020-01-03 00:00:00 │ imp │ safary │ 16 │ 6.14 │
│ 2020-01-03 00:00:00 │ imp │ chrome │ 16 │ 7.89 │
│ 2020-01-04 00:00:00 │ click │ safary │ 1 │ 0.1 │
│ 2020-01-04 00:00:00 │ click │ firefox │ 1 │ 0.1 │
│ 2020-01-04 00:00:00 │ imp │ firefox │ 1 │ 0.1 │
│ 2020-01-04 00:00:00 │ imp │ chrome │ 1 │ 0.1 │
└─────────────────────┴────────────┴─────────┴────────────┴───────┘
-- !!! During `MODIFY ORDER BY` PRIMARY KEY was implicitly introduced.
SHOW CREATE TABLE events_by_day FORMAT TSVRaw
CREATE TABLE test.events_by_day
(
`ts` DateTime,
`event_type` String,
`browser` String,
`events_cnt` UInt64,
`cost` Float64
)
ENGINE = SummingMergeTree
PRIMARY KEY (event_type, ts)
ORDER BY (event_type, ts, browser)
SETTINGS index_granularity = 8192
-- !!! The columns' definition is unchanged but it does not matter, we are not querying
-- MATERIALIZED VIEW, we are querying TO (storage) table.
2023-03-19 17:01:47 +00:00
-- SELECT section is updated.
SHOW CREATE TABLE mv FORMAT TSVRaw;
CREATE MATERIALIZED VIEW test.mv TO test.events_by_day
(
`ts` DateTime,
`event_type` String,
`events_cnt` UInt64
) AS
SELECT
toStartOfDay(ts) AS ts,
event_type,
browser,
count() AS events_cnt,
sum(cost) AS cost
FROM test.events
GROUP BY
ts,
event_type,
browser
```
**Example without TO table**
2023-03-19 17:05:39 +00:00
The application is very limited because you can only change the `SELECT` section without adding new columns.
```sql
CREATE TABLE src_table (`a` UInt32) ENGINE = MergeTree ORDER BY a;
2023-12-01 01:26:44 +00:00
CREATE MATERIALIZED VIEW mv (`a` UInt32) ENGINE = MergeTree ORDER BY a AS SELECT a FROM src_table;
INSERT INTO src_table (a) VALUES (1), (2);
SELECT * FROM mv;
```
```text
┌─a─┐
│ 1 │
│ 2 │
└───┘
```
```sql
ALTER TABLE mv MODIFY QUERY SELECT a * 2 as a FROM src_table;
INSERT INTO src_table (a) VALUES (3), (4);
SELECT * FROM mv;
```
```text
┌─a─┐
│ 6 │
│ 8 │
└───┘
┌─a─┐
│ 1 │
│ 2 │
└───┘
```
2022-06-02 10:55:18 +00:00
## ALTER LIVE VIEW Statement
`ALTER LIVE VIEW ... REFRESH` statement refreshes a [Live view](../create/view.md#live-view). See [Force Live View Refresh](../create/view.md#live-view-alter-refresh).
2023-12-01 01:26:44 +00:00
## ALTER TABLE ... MODIFY REFRESH Statement
2023-12-01 01:26:44 +00:00
`ALTER TABLE ... MODIFY REFRESH` statement changes refresh parameters of a [Refreshable Materialized View](../create/view.md#refreshable-materialized-view). See [Changing Refresh Parameters](../create/view.md#changing-refresh-parameters).