- Release Notes
- Get Started
- Clusters
- Cloud Settings
- Table Type
- Query Data Lakes
- Integration
- Query Acceleration
- Data Loading
- Concepts
- Batch load data from Amazon S3
- Batch load data from Azure cloud storage
- Load data from a local file system
- Load data from Confluent Cloud
- Load data from Amazon MSK
- Load data from Amazon Kinesis
- Data Unloading
- Data Backup
- Security
- Console Access Control
- Data Access Control
- Application keys
- Service accounts
- Use SSL connection
- Alarm
- Usage and Billing
- Organizations and Accounts
- Reference
- Amazon Web Services (AWS)
- Microsoft Azure
- SQL Reference
- Keywords
- ALL statements
- User Account Management
- Cluster Management
- ADMIN CANCEL REPAIR
- ADMIN CHECK TABLET
- ADMIN REPAIR
- ADMIN SET CONFIG
- ADMIN SET REPLICA STATUS
- ADMIN SHOW CONFIG
- ADMIN SHOW REPLICA DISTRIBUTION
- ADMIN SHOW REPLICA STATUS
- ALTER RESOURCE GROUP
- ALTER SYSTEM
- CANCEL DECOMMISSION
- CREATE FILE
- CREATE RESOURCE GROUP
- DROP FILE
- DROP RESOURCE GROUP
- EXPLAIN
- INSTALL PLUGIN
- SET
- SHOW BACKENDS
- SHOW BROKER
- SHOW COMPUTE NODES
- SHOW FRONTENDS
- SHOW FULL COLUMNS
- SHOW INDEX
- SHOW PLUGINS
- SHOW PROCESSLIST
- SHOW RESOURCE GROUP
- SHOW TABLE STATUS
- SHOW FILE
- SHOW VARIABLES
- UNINSTALL PLUGIN
- DDL
- ALTER DATABASE
- ALTER MATERIALIZED VIEW
- ALTER TABLE
- ALTER VIEW
- ANALYZE TABLE
- BACKUP
- CANCEL ALTER TABLE
- CANCEL BACKUP
- CANCEL RESTORE
- CREATE ANALYZE
- CREATE DATABASE
- CREATE EXTERNAL CATALOG
- CREATE INDEX
- CREATE MATERIALIZED VIEW
- CREATE REPOSITORY
- CREATE TABLE AS SELECT
- CREATE TABLE LIKE
- CREATE TABLE
- CREATE VIEW
- CREATE FUNCTION
- DROP ANALYZE
- DROP STATS
- DROP CATALOG
- DROP DATABASE
- DROP INDEX
- DROP MATERIALIZED VIEW
- DROP REPOSITORY
- DROP TABLE
- DROP VIEW
- DROP FUNCTION
- KILL ANALYZE
- RECOVER
- REFRESH EXTERNAL TABLE
- RESTORE
- SET CATALOG
- SHOW ANALYZE JOB
- SHOW ANALYZE STATUS
- SHOW META
- SHOW FUNCTION
- TRUNCATE TABLE
- USE
- DML
- ALTER LOAD
- ALTER ROUTINE LOAD
- BROKER LOAD
- CANCEL LOAD
- CANCEL EXPORT
- CANCEL REFRESH MATERIALIZED VIEW
- CREATE ROUTINE LOAD
- DELETE
- EXPORT
- GROUP BY
- INSERT
- PAUSE ROUTINE LOAD
- RESUME ROUTINE LOAD
- REFRESH MATERIALIZED VIEW
- SELECT
- SHOW ALTER
- SHOW ALTER MATERIALIZED VIEW
- SHOW BACKUP
- SHOW CATALOGS
- SHOW CREATE CATALOG
- SHOW CREATE MATERIALIZED VIEW
- SHOW CREATE TABLE
- SHOW CREATE VIEW
- SHOW DATA
- SHOW DATABASES
- SHOW DELETE
- SHOW DYNAMIC PARTITION TABLES
- SHOW EXPORT
- SHOW LOAD
- SHOW MATERIALIZED VIEW
- SHOW PARTITIONS
- SHOW REPOSITORIES
- SHOW RESTORE
- SHOW ROUTINE LOAD
- SHOW ROUTINE LOAD TASK
- SHOW SNAPSHOT
- SHOW TABLES
- SHOW TABLET
- SHOW TRANSACTION
- STOP ROUTINE LOAD
- STREAM LOAD
- SUBMIT TASK
- UPDATE
- Auxiliary Commands
- Data Types
- Keywords
- SQL Functions
- Function list
- Java UDFs
- Window functions
- Lambda expression
- Date Functions
- add_months
- adddate
- convert_tz
- current_date
- current_time
- current_timestamp
- date
- date_add
- date_diff
- date_format
- date_slice
- date_sub, subdate
- date_trunc
- datediff
- day
- dayofweek_iso
- dayname
- dayofmonth
- dayofweek
- dayofyear
- days_add
- days_diff
- days_sub
- from_days
- from_unixtime
- hour
- hours_add
- hours_diff
- hours_sub
- jodatime_format
- last_day
- makedate
- microseconds_add
- microseconds_sub
- minute
- minutes_add
- minutes_diff
- minutes_sub
- month
- monthname
- months_add
- months_diff
- months_sub
- next_day
- now
- previous_day
- quarter
- second
- seconds_add
- seconds_diff
- seconds_sub
- str_to_date
- str_to_jodatime
- str2date
- time_slice
- time_to_sec
- timediff
- timestamp
- timestampadd
- timestampdiff
- to_date
- to_days
- to_iso8601
- to_tera_date
- to_tera_timestamp
- unix_timestamp
- utc_timestamp
- week
- week_iso
- weekofyear
- weeks_add
- weeks_diff
- weeks_sub
- year
- years_add
- years_diff
- years_sub
- Aggregate Functions
- any_value
- approx_count_distinct
- array_agg
- avg
- bitmap
- bitmap_agg
- count
- count_if
- corr
- covar_pop
- covar_samp
- group_concat
- grouping
- grouping_id
- hll_empty
- hll_hash
- hll_raw_agg
- hll_union
- hll_union_agg
- max
- max_by
- min
- min_by
- multi_distinct_sum
- multi_distinct_count
- percentile_approx
- percentile_cont
- percentile_disc
- retention
- stddev
- stddev_samp
- sum
- variance, variance_pop, var_pop
- var_samp
- window_funnel
- Geographic Functions
- String Functions
- append_trailing_char_if_absent
- ascii
- char
- char_length
- character_length
- concat
- concat_ws
- ends_with
- find_in_set
- group_concat
- hex
- hex_decode_binary
- hex_decode_string
- instr
- lcase
- left
- length
- locate
- lower
- lpad
- ltrim
- money_format
- null_or_empty
- parse_url
- repeat
- replace
- reverse
- right
- rpad
- rtrim
- space
- split
- split_part
- substring_index
- starts_with
- strleft
- strright
- str_to_map
- substring
- trim
- ucase
- unhex
- upper
- url_decode
- url_encode
- Pattern Matching Functions
- JSON Functions
- Overview of JSON functions and operators
- JSON operators
- JSON constructor functions
- JSON query and processing functions
- Bit Functions
- Bitmap Functions
- Array Functions
- all_match
- any_match
- array_agg
- array_append
- array_avg
- array_concat
- array_contains
- array_contains_all
- array_cum_sum
- array_difference
- array_distinct
- array_filter
- array_generate
- array_intersect
- array_join
- array_length
- array_map
- array_max
- array_min
- array_position
- array_remove
- array_slice
- array_sort
- array_sortby
- array_sum
- arrays_overlap
- array_to_bitmap
- cardinality
- element_at
- reverse
- unnest
- Map Functions
- Binary Functions
- cast function
- hash function
- Cryptographic Functions
- Math Functions
- Pattern Matching Functions
- Percentile Functions
- Scalar Functions
- Struct Functions
- Table Functions
- Utility Functions
- AUTO_INCREMENT
- Generated columns
- System variables
- System limits
- Information Schema
- Overview
- be_bvars
- be_cloud_native_compactions
- be_compactions
- character_sets
- collations
- column_privileges
- columns
- engines
- events
- global_variables
- key_column_usage
- load_tracking_logs
- loads
- materialized_views
- partitions
- pipe_files
- pipes
- referential_constraints
- routines
- schema_privileges
- schemata
- session_variables
- statistics
- table_constraints
- table_privileges
- tables
- tables_config
- task_runs
- tasks
- triggers
- user_privileges
- views
- System Metadatabase
- API
- Overview
- Actions
- Clusters
- Create and Manage Clusters
- Query Clusters
- Identity and Access Management
- Organization and Account
- Usage and Billing
- Clusters
- Terraform Provider
- Run scripts
ALTER TABLE
Description
Modifies an existing table.
NOTE
This operation requires the ALTER privilege on the destination table.
Syntax
ALTER TABLE [database.]table
alter_clause1[, alter_clause2, ...]
alter_clause
is classified into six operations: partition, rollup, schema change, rename, index, swap, and comment.
- partition: modifies partition properties, drops a partition, or adds a partition.
- rollup: creates or drops a rollup index.
- schema change: adds, drops, or reorder columns, or modify column type.
- rename: renames a table, rollup index, or partition. Note that column name cannot be modified.
- index: modifies index (only Bitmap index can be modified).
- swap: atomic exchange of two tables.
- comment: modifies the table comment.
NOTE
- Schema change, rollup, and partition cannot be used in one ALTER TABLE statement.
- Schema change, rollup, and swap are asynchronous operations and are returned if the task is submitted successfully. User can use the SHOW ALTER TABLE command to check the progress.
- Partition, rename, and index are synchronous operations, and a command return indicates that the execution is finished.
Modify partition
Add a partition
Syntax:
ALTER TABLE [database.]table
ADD PARTITION [IF NOT EXISTS] <partition_name>
partition_desc ["key"="value"]
[DISTRIBUTED BY HASH (k1[,k2 ...]) [BUCKETS num]];
Note:
Partition_desc supports the following two expressions:
VALUES LESS THAN [MAXVALUE|("value1", ...)] VALUES [("value1", ...), ("value1", ...))
partition is the left-closed-right-open interval. If the user only specifies the right boundary, the system will automatically determine the left boundary.
If the bucket mode is not specified, the bucket method used by the built-in table is automatically used.
If the bucket mode is specified, only the bucket number can be modified, and the bucket mode or bucket column cannot be modified.
User can set some properties of the partition in ["key"="value"]. See CREATE TABLE for details.
Drop a partition
Syntax:
-- Before 2.0
ALTER TABLE [database.]table
DROP PARTITION [IF EXISTS | FORCE] <partition_name>
-- 2.0 or later
ALTER TABLE [database.]table
DROP PARTITION [IF EXISTS] <partition_name> [FORCE]
Note:
- Keep at least one partition for partitioned tables.
- After executing DROP PARTITION for a while, the dropped partition can be recovered by the RECOVER statement. See the RECOVER statement for details.
- If DROP PARTITION FORCE is executed, the partition will be deleted directly and cannot be recovered without checking whether there are any unfinished activities on the partition. Thus, generally this operation is not recommended.
Add a temporary partition
Syntax:
ALTER TABLE [database.]table
ADD TEMPORARY PARTITION [IF NOT EXISTS] <partition_name>
partition_desc ["key"="value"]
[DISTRIBUTED BY HASH (k1[,k2 ...]) [BUCKETS num]]
Use a temporary partition to replace current partition
Syntax:
ALTER TABLE [database.]table
REPLACE PARTITION <partition_name>
partition_desc ["key"="value"]
WITH TEMPORARY PARTITION
partition_desc ["key"="value"]
[PROPERTIES ("key"="value", ...)]
Drop a temporary partition
Syntax:
ALTER TABLE [database.]table
DROP TEMPORARY PARTITION <partition_name>
Modify partition properties
Syntax:
ALTER TABLE [database.]table
MODIFY PARTITION p1|(p1[, p2, ...]) SET ("key" = "value", ...)
Note:
The following properties of a partition can be modified:
- storage_medium
- storage_cooldown_time
- replication_num
For single-partition tables, partition name is the same as the table name.
Modify rollup index
Create a rollup index
Syntax:
ALTER TABLE [database.]table
ADD ROLLUP rollup_name (column_name1, column_name2, ...)
[FROM from_index_name]
[PROPERTIES ("key"="value", ...)]
PROPERTIES: Support setting timeout time and the default timeout time is one day.
Example:
ALTER TABLE [database.]table
ADD ROLLUP r1(col1,col2) from r0;
Create rollup indexes in batches
Syntax:
ALTER TABLE [database.]table
ADD ROLLUP [rollup_name (column_name1, column_name2, ...)
[FROM from_index_name]
[PROPERTIES ("key"="value", ...)],...];
Example:
ALTER TABLE [database.]table
ADD ROLLUP r1(col1,col2) from r0, r2(col3,col4) from r0;
Note:
- If from_index_name is not specified, then create from base index by default.
- The columns in the rollup table must be existing columns in from_index.
- In properties, user can specify the storage format. See CREATE TABLE for details.
Drop a rollup index
Syntax:
ALTER TABLE [database.]table
DROP ROLLUP rollup_name [PROPERTIES ("key"="value", ...)];
Example:
ALTER TABLE [database.]table DROP ROLLUP r1;
Batch drop rollup indexes
Syntax:
ALTER TABLE [database.]table
DROP ROLLUP [rollup_name [PROPERTIES ("key"="value", ...)],...];
Example:
ALTER TABLE [database.]table DROP ROLLUP r1, r2;
Note: You cannot drop the base index.
Schema change
Schema change supports the following modifications.
Add a column to specified location of specified index
Syntax:
ALTER TABLE [database.]table
ADD COLUMN column_name column_type [KEY | agg_type] [DEFAULT "default_value"]
[AFTER column_name|FIRST]
[TO rollup_index_name]
[PROPERTIES ("key"="value", ...)]
Note:
1. If you add a value column to an Aggregate table, you need to specify agg_type.
2. If you add a key column to a non-Aggregate table (such as a Duplicate Key table), you need to specify the KEY keyword.
3. You cannot add a column that already exists in the base index to the rollup index. (You can recreate a rollup index if needed.)
Add multiple columns to specified index
Syntax:
ALTER TABLE [database.]table
ADD COLUMN (column_name1 column_type [KEY | agg_type] DEFAULT "default_value", ...)
[TO rollup_index_name]
[PROPERTIES ("key"="value", ...)]
Note:
If you add a value column to an aggregate table, you need to specify
agg_type
.If you add a key column to a non-aggregate table, you need to specify the KEY keyword.
You cannot add a column that already exists in the base index to the rollup index. (You can create another rollup index if needed.)
Drop a column from specified index
Syntax:
ALTER TABLE [database.]table
DROP COLUMN column_name
[FROM rollup_index_name];
Note:
- You cannot drop partition column.
- If the column is dropped from the base index, it will also be dropped if it is included in the rollup index.
Modify the column type and column position of specified index
Syntax:
ALTER TABLE [database.]table
MODIFY COLUMN column_name column_type [KEY | agg_type] [NULL | NOT NULL] [DEFAULT "default_value"]
[AFTER column_name|FIRST]
[FROM rollup_index_name]
[PROPERTIES ("key"="value", ...)]
Note:
If you modify the value column in aggregation models, you need to specify agg_type.
If you modify the key column in non-aggregation models, you need to specify the KEY keyword.
Only the type of column can be modified. The other properties of the column remain as they are currently. (i.e. other properties need to be explicitly written in the statement according to the original property, see example 8).
The partition column cannot be modified.
The following types of conversions are currently supported (accuracy loss is guaranteed by the user).
- Convert TINYINT/SMALLINT/INT/BIGINT to TINYINT/SMALLINT/INT/BIGINT/DOUBLE.
- Convert TINTINT/SMALLINT/INT/BIGINT/LARGEINT/FLOAT/DOUBLE/DECIMAL to VARCHAR. VARCHAR supports modification of maximum length.
- Convert VARCHAR to TINTINT/SMALLINT/INT/BIGINT/LARGEINT/FLOAT/DOUBLE.
- Convert VARCHAR to DATE (currently support six formats: "%Y-%m-%d", "%y-%m-%d", "%Y%m%d", "%y%m%d", "%Y/%m/%d, "%y/%m/%d")
- Convert DATETIME to DATE(only year-month-day information is retained, i.e.
2019-12-09 21:47:05
<-->2019-12-09
) - Convert DATE to DATETIME (set hour, minute, second to zero, For example:
2019-12-09
<-->2019-12-09 00:00:00
) - Convert FLOAT to DOUBLE
- Convert INT to DATE (If the INT data fails to convert, the original data remains the same)
Conversion from NULL to NOT NULL is not supported.
Reorder the columns of specified index
Syntax:
ALTER TABLE [database.]table
ORDER BY (column_name1, column_name2, ...)
[FROM rollup_index_name]
[PROPERTIES ("key"="value", ...)]
Note:
- All columns in the index must be written.
- The value column is listed after the key column.
Modify table properties
Currently, CelerData supports modifying bloomfilter columns, colocate_with property, dynamic_partition property, enable_persistent_index property, replication_num property and default.replication_num property.
Syntax:
PROPERTIES ("key"="value")
Note: You can also modify the properties by merging into the above schema change operation. See the following examples.
Rename
Rename supports modification of table name, rollup index, and partition name.
Rename a table
ALTER TABLE <table_name> RENAME <new_table_name>
Rename a rollup index
ALTER TABLE [database.]table
RENAME ROLLUP <old_rollup_name> <new_rollup_name>
Rename a partition
ALTER TABLE [database.]table
RENAME PARTITION <old_partition_name> <new_partition_name>
Modify bitmap indexes
Bitmap index supports the following modifications:
Create a bitmap index
Syntax:
ALTER TABLE [database.]table
ADD INDEX index_name (column [, ...],) [USING BITMAP] [COMMENT 'balabala'];
Note:
1. Bitmap index is only supported for the current version.
2. A BITMAP index is created only in a single column.
Drop an index
Syntax:
DROP INDEX index_name;
Swap
Swap supports atomic exchange of two tables.
Syntax:
ALTER TABLE [database.]table
SWAP WITH table_name;
Alter table comment
Syntax:
ALTER TABLE [database.]table COMMENT = "<new table comment>";
Examples
Table
Modify the default number of replicas of the table, which is used as the default number of replicas for newly added partitions.
ALTER TABLE example_db.my_table SET ("default.replication_num" = "2");
Modify the actual number of replicas of a single-partition table.
ALTER TABLE example_db.my_table SET ("replication_num" = "3");
Modify data writing and replication mode among replicas.
ALTER TABLE example_db.my_table SET ("replicated_storage" = "false");
This example sets the data writing and replication mode among replicas to "leaderless replication", which means data is written to multiple replicas at the same time without differentiating primary and secondary replicas. For more information, see the
replicated_storage
parameter in CREATE TABLE.
Partition
Add a partition and use the default bucketing mode. The existing partition is [MIN, 2013-01-01). The added partition is [2013-01-01, 2014-01-01).
ALTER TABLE example_db.my_table ADD PARTITION p1 VALUES LESS THAN ("2014-01-01");
Add a partition and use the new number of buckets.
ALTER TABLE example_db.my_table ADD PARTITION p1 VALUES LESS THAN ("2015-01-01") DISTRIBUTED BY HASH(k1);
Add a partition and use the new number of replicas.
ALTER TABLE example_db.my_table ADD PARTITION p1 VALUES LESS THAN ("2015-01-01") ("replication_num"="1");
Alter the number of replicas for a partition.
ALTER TABLE example_db.my_table MODIFY PARTITION p1 SET("replication_num"="1");
Batch alter the number of replicas for specified partitions.
ALTER TABLE example_db.my_table MODIFY PARTITION (p1, p2, p4) SET("replication_num"="1");
Batch alter the storage medium of all partitions.
ALTER TABLE example_db.my_table MODIFY PARTITION (*) SET("storage_medium"="HDD");
Drop a partition.
ALTER TABLE example_db.my_table DROP PARTITION p1;
Add a partition that has upper and lower boundaries.
ALTER TABLE example_db.my_table ADD PARTITION p1 VALUES [("2014-01-01"), ("2014-02-01"));
Rollup
Create an index
example_rollup_index
based on the base index (k1,k2,k3,v1,v2). Column-based storage is used.ALTER TABLE example_db.my_table ADD ROLLUP example_rollup_index(k1, k3, v1, v2) PROPERTIES("storage_type"="column");
Create an index
example_rollup_index2
based onexample_rollup_index(k1,k3,v1,v2)
.ALTER TABLE example_db.my_table ADD ROLLUP example_rollup_index2 (k1, v1) FROM example_rollup_index;
Create an index
example_rollup_index3
based on the base index (k1, k2, k3, v1). The rollup timeout time is set to one hour.ALTER TABLE example_db.my_table ADD ROLLUP example_rollup_index3(k1, k3, v1) PROPERTIES("storage_type"="column", "timeout" = "3600");
Drop an index
example_rollup_index2
.ALTER TABLE example_db.my_table DROP ROLLUP example_rollup_index2;
Schema Change
Add a key column
new_col
(non-aggregate column) after thecol1
column ofexample_rollup_index
.ALTER TABLE example_db.my_table ADD COLUMN new_col INT KEY DEFAULT "0" AFTER col1 TO example_rollup_index;
Add a value column
new_col
(non-aggregate column) after thecol1
column ofexample_rollup_index
.ALTER TABLE example_db.my_table ADD COLUMN new_col INT DEFAULT "0" AFTER col1 TO example_rollup_index;
Add a key column
new_col
(aggregate column) after thecol1
column ofexample_rollup_index
.ALTER TABLE example_db.my_table ADD COLUMN new_col INT DEFAULT "0" AFTER col1 TO example_rollup_index;
Add a value column
new_col SUM
(aggregate column) after thecol1
column ofexample_rollup_index
.ALTER TABLE example_db.my_table ADD COLUMN new_col INT SUM DEFAULT "0" AFTER col1 TO example_rollup_index;
Add multiple columns to
example_rollup_index
(aggregate).ALTER TABLE example_db.my_table ADD COLUMN (col1 INT DEFAULT "1", col2 FLOAT SUM DEFAULT "2.3") TO example_rollup_index;
Drop a column from
example_rollup_index
.ALTER TABLE example_db.my_table DROP COLUMN col2 FROM example_rollup_index;
Modify the column type of col1 of the base index to BIGINT and put it after
col2
.ALTER TABLE example_db.my_table MODIFY COLUMN col1 BIGINT DEFAULT "1" AFTER col2;
Modify the maximum length of the
val1
column of the base index to 64. The original length is 32.ALTER TABLE example_db.my_table MODIFY COLUMN val1 VARCHAR(64) REPLACE DEFAULT "abc";
Reorder the columns in
example_rollup_index
. The original column order is k1, k2, k3, v1, v2.ALTER TABLE example_db.my_table ORDER BY (k3,k1,k2,v2,v1) FROM example_rollup_index;
Perform two operations (ADD COLUMN and ORDER BY) at one time.
ALTER TABLE example_db.my_table ADD COLUMN v2 INT MAX DEFAULT "0" AFTER k2 TO example_rollup_index, ORDER BY (k3,k1,k2,v2,v1) FROM example_rollup_index;
Alter the bloomfilter columns of the table.
ALTER TABLE example_db.my_table SET ("bloom_filter_columns"="k1,k2,k3");
This operation can also be merged into the above schema change operation (note that the syntax of multiple clauses is slightly different).
ALTER TABLE example_db.my_table DROP COLUMN col2 PROPERTIES ("bloom_filter_columns"="k1,k2,k3");
Alter the Colocate property of the table.
ALTER TABLE example_db.my_table SET ("colocate_with" = "t1");
Alter the bucketing mode of the table from Random Distribution to Hash Distribution.
ALTER TABLE example_db.my_table SET ("distribution_type" = "hash");
Alter the dynamic partition property of the table.
ALTER TABLE example_db.my_table SET ("dynamic_partition.enable" = "false");
If you need to add dynamic partition properties to a table with no dynamic partition properties configured, you need to specify all the dynamic partition properties.
ALTER TABLE example_db.my_table SET ( "dynamic_partition.enable" = "true", "dynamic_partition.time_unit" = "DAY", "dynamic_partition.end" = "3", "dynamic_partition.prefix" = "p", "dynamic_partition.buckets" = "32" );
Rename
Rename
table1
totable2
.ALTER TABLE table1 RENAME table2;
Rename rollup index
rollup1
ofexample_table
torollup2
.ALTER TABLE example_table RENAME ROLLUP rollup1 rollup2;
Rename partition
p1
ofexample_table
top2
.ALTER TABLE example_table RENAME PARTITION p1 p2;
Index
Create a bitmap index for column
siteid
intable1
.ALTER TABLE table1 ADD INDEX index_1 (siteid) [USING BITMAP] COMMENT 'balabala';
Drop the bitmap index of column
siteid
intable1
.ALTER TABLE table1 DROP INDEX index_1;
Swap
Atomic swap between
table1
andtable2
.ALTER TABLE table1 SWAP WITH table2