Column Manipulations
A set of queries that allow changing the table structure.
Syntax:
ALTER [TEMPORARY] TABLE [db].name [ON CLUSTER cluster] ADD|DROP|RENAME|CLEAR|COMMENT|{MODIFY|ALTER}|MATERIALIZE COLUMN ...
In the query, specify a list of one or more comma-separated actions. Each action is an operation on a column.
The following actions are supported:
- ADD COLUMN — Adds a new column to the table.
- DROP COLUMN — Deletes the column.
- RENAME COLUMN — Renames an existing column.
- CLEAR COLUMN — Resets column values.
- COMMENT COLUMN — Adds a text comment to the column.
- MODIFY COLUMN — Changes column’s type, default expression, TTL, and column settings.
- MODIFY COLUMN REMOVE — Removes one of the column properties.
- MODIFY COLUMN MODIFY SETTING - Changes column settings.
- MODIFY COLUMN RESET SETTING - Reset column settings.
- MATERIALIZE COLUMN — Materializes the column in the parts where the column is missing. These actions are described in detail below.
ADD COLUMN
ADD COLUMN [IF NOT EXISTS] name [type] [default_expr] [codec] [AFTER name_after | FIRST]
Adds a new column to the table with the specified
name
,
type
,
codec
and
default_expr
(see the section
Default expressions
).
If the
IF NOT EXISTS
clause is included, the query won’t return an error if the column already exists. If you specify
AFTER name_after
(the name of another column), the column is added after the specified one in the list of table columns. If you want to add a column to the beginning of the table use the
FIRST
clause. Otherwise, the column is added to the end of the table. For a chain of actions,
name_after
can be the name of a column that is added in one of the previous actions.
Adding a column just changes the table structure, without performing any actions with data. The data does not appear on the disk after
ALTER
. If the data is missing for a column when reading from the table, it is filled in with default values (by performing the default expression if there is one, or using zeros or empty strings). The column appears on the disk after merging data parts (see
MergeTree
).
This approach allows us to complete the
ALTER
query instantly, without increasing the volume of old data.
Example:
ALTER TABLE alter_test ADD COLUMN Added1 UInt32 FIRST;
ALTER TABLE alter_test ADD COLUMN Added2 UInt32 AFTER NestedColumn;
ALTER TABLE alter_test ADD COLUMN Added3 UInt32 AFTER ToDrop;
DESC alter_test FORMAT TSV;
Added1 UInt32
CounterID UInt32
StartDate Date
UserID UInt32
VisitID UInt32
NestedColumn.A Array(UInt8)
NestedColumn.S Array(String)
Added2 UInt32
ToDrop UInt32
Added3 UInt32
DROP COLUMN
DROP COLUMN [IF EXISTS] name
Deletes the column with the name
name
. If the
IF EXISTS
clause is specified, the query won’t return an error if the column does not exist.
Deletes data from the file system. Since this deletes entire files, the query is completed almost instantly.
You can’t delete a column if it is referenced by materialized view . Otherwise, it returns an error.
Example:
ALTER TABLE visits DROP COLUMN browser
RENAME COLUMN
RENAME COLUMN [IF EXISTS] name to new_name
Renames the column
name
to
new_name
. If the
IF EXISTS
clause is specified, the query won’t return an error if the column does not exist. Since renaming does not involve the underlying data, the query is completed almost instantly.
NOTE
: Columns specified in the key expression of the table (either with
ORDER BY
or
PRIMARY KEY
) cannot be renamed. Trying to change these columns will produce
SQL Error [524]
.
Example:
ALTER TABLE visits RENAME COLUMN webBrowser TO browser
CLEAR COLUMN
CLEAR COLUMN [IF EXISTS] name IN PARTITION partition_name
Resets all data in a column for a specified partition. Read more about setting the partition name in the section How to set the partition expression .
If the
IF EXISTS
clause is specified, the query won’t return an error if the column does not exist.
Example:
ALTER TABLE visits CLEAR COLUMN browser IN PARTITION tuple()
COMMENT COLUMN
COMMENT COLUMN [IF EXISTS] name 'Text comment'
Adds a comment to the column. If the
IF EXISTS
clause is specified, the query won’t return an error if the column does not exist.
Each column can have one comment. If a comment already exists for the column, a new comment overwrites the previous comment.
Comments are stored in the
comment_expression
column returned by the
DESCRIBE TABLE
query.
Example:
ALTER TABLE visits COMMENT COLUMN browser 'This column shows the browser used for accessing the site.'
MODIFY COLUMN
MODIFY COLUMN [IF EXISTS] name [type] [default_expr] [codec] [TTL] [settings] [AFTER name_after | FIRST]
ALTER COLUMN [IF EXISTS] name TYPE [type] [default_expr] [codec] [TTL] [settings] [AFTER name_after | FIRST]
This query changes the
name
column properties:
-
Type
-
Default expression
-
Compression Codec
-
TTL
-
Column-level Settings
For examples of columns compression CODECS modifying, see Column Compression Codecs .
For examples of columns TTL modifying, see Column TTL .
For examples of column-level settings modifying, see Column-level Settings .
If the
IF EXISTS
clause is specified, the query won’t return an error if the column does not exist.
When changing the type, values are converted as if the toType functions were applied to them. If only the default expression is changed, the query does not do anything complex, and is completed almost instantly.
Example:
ALTER TABLE visits MODIFY COLUMN browser Array(String)
Changing the column type is the only complex action – it changes the contents of files with data. For large tables, this may take a long time.
The query also can change the order of the columns using
FIRST | AFTER
clause, see
ADD COLUMN
description, but column type is mandatory in this case.
Example:
CREATE TABLE users (
c1 Int16,
c2 String
) ENGINE = MergeTree
ORDER BY c1;
DESCRIBE users;
┌─name─┬─type───┬
│ c1 │ Int16 │
│ c2 │ String │
└──────┴────────┴
ALTER TABLE users MODIFY COLUMN c2 String FIRST;
DESCRIBE users;
┌─name─┬─type───┬
│ c2 │ String │
│ c1 │ Int16 │
└──────┴────────┴
ALTER TABLE users ALTER COLUMN c2 TYPE String AFTER c1;
DESCRIBE users;
┌─name─┬─type───┬
│ c1 │ Int16 │
│ c2 │ String │
└──────┴────────┴
The
ALTER
query is atomic. For MergeTree tables it is also lock-free.
The
ALTER
query for changing columns is replicated. The instructions are saved in ZooKeeper, then each replica applies them. All
ALTER
queries are run in the same order. The query waits for the appropriate actions to be completed on the other replicas. However, a query to change columns in a replicated table can be interrupted, and all actions will be performed asynchronously.
MODIFY COLUMN REMOVE
Removes one of the column properties:
DEFAULT
,
ALIAS
,
MATERIALIZED
,
CODEC
,
COMMENT
,
TTL
,
SETTINGS
.
Syntax:
ALTER TABLE table_name MODIFY COLUMN column_name REMOVE property;
Example
Remove TTL:
ALTER TABLE table_with_ttl MODIFY COLUMN column_ttl REMOVE TTL;
See Also
MODIFY COLUMN MODIFY SETTING
Modify a column setting.
Syntax:
ALTER TABLE table_name MODIFY COLUMN column_name MODIFY SETTING name=value,...;
Example
Modify column's
max_compress_block_size
to
1MB
:
ALTER TABLE table_name MODIFY COLUMN column_name MODIFY SETTING max_compress_block_size = 1048576;
MODIFY COLUMN RESET SETTING
Reset a column setting, also removes the setting declaration in the column expression of the table's CREATE query.
Syntax:
ALTER TABLE table_name MODIFY COLUMN column_name RESET SETTING name,...;
Example
Reset column setting
max_compress_block_size
to it's default value:
ALTER TABLE table_name MODIFY COLUMN column_name RESET SETTING max_compress_block_size;
MATERIALIZE COLUMN
Materializes a column with a
DEFAULT
or
MATERIALIZED
value expression.