ALTER TABLE

描述

ALTER TABLE 语句用于更改表的架构或属性。

RENAME

ALTER TABLE RENAME TO 语句用于更改数据库中现有表的表名。表重命名命令不能用于在数据库之间移动表,只能用于重命名同一数据库中的表。

如果表已缓存,则这些命令会清除表的缓存数据。下次访问该表时,缓存将被延迟填充。此外

语法

ALTER TABLE table_identifier RENAME TO table_identifier

ALTER TABLE table_identifier partition_spec RENAME TO partition_spec

参数

ADD COLUMNS

ALTER TABLE ADD COLUMNS 语句用于将提到的列添加到现有表中。

语法

ALTER TABLE table_identifier ADD COLUMNS ( col_spec [ , ... ] )

参数

DROP COLUMNS

ALTER TABLE DROP COLUMNS 语句用于从现有表中删除提到的列。请注意,此语句仅在 v2 表中受支持。

语法

ALTER TABLE table_identifier DROP { COLUMN | COLUMNS } [ ( ] col_name [ , ... ] [ ) ]

参数

RENAME COLUMN

ALTER TABLE RENAME COLUMN 语句用于更改现有表的列名。请注意,此语句仅在 v2 表中受支持。

语法

ALTER TABLE table_identifier RENAME COLUMN col_name TO col_name

参数

ALTER OR CHANGE COLUMN

ALTER TABLE ALTER COLUMNALTER TABLE CHANGE COLUMN 语句用于更改列的定义。

语法

ALTER TABLE table_identifier { ALTER | CHANGE } [ COLUMN ] col_name alterColumnAction

参数

REPLACE COLUMNS

ALTER TABLE REPLACE COLUMNS 语句用于删除所有现有列并添加新的列集。请注意,此语句仅在 v2 表中受支持。

语法

ALTER TABLE table_identifier [ partition_spec ] REPLACE COLUMNS  
  [ ( ] qualified_col_type_with_position_list [ ) ]

参数

ADD AND DROP PARTITION

ADD PARTITION

ALTER TABLE ADD 语句用于将分区添加到分区表中。

如果表已缓存,则该命令会清除表及其所有引用它的依赖项的缓存数据。下次访问该表或依赖项时,缓存将被延迟填充。

语法
ALTER TABLE table_identifier ADD [IF NOT EXISTS] 
    ( partition_spec [ partition_spec ... ] )
参数

DROP PARTITION

ALTER TABLE DROP 语句用于删除表的分区。

如果表已缓存,则该命令会清除表及其所有引用它的依赖项的缓存数据。下次访问该表或依赖项时,缓存将被延迟填充。

语法
ALTER TABLE table_identifier DROP [ IF EXISTS ] partition_spec [PURGE]
参数

SET AND UNSET

SET TABLE PROPERTIES

ALTER TABLE SET 命令用于设置表属性。如果已设置特定属性,则会使用新值覆盖旧值。

ALTER TABLE UNSET 用于删除表属性。

语法
-- Set Table Properties 
ALTER TABLE table_identifier SET TBLPROPERTIES ( key1 = val1, key2 = val2, ... )

-- Unset Table Properties
ALTER TABLE table_identifier UNSET TBLPROPERTIES [ IF EXISTS ] ( key1, key2, ... )

SET SERDE

ALTER TABLE SET 命令用于在 Hive 表中设置 SERDE 或 SERDE 属性。如果已设置特定属性,则会使用新值覆盖旧值。

语法
-- Set SERDE Properties
ALTER TABLE table_identifier [ partition_spec ]
    SET SERDEPROPERTIES ( key1 = val1, key2 = val2, ... )

ALTER TABLE table_identifier [ partition_spec ] SET SERDE serde_class_name
    [ WITH SERDEPROPERTIES ( key1 = val1, key2 = val2, ... ) ]

SET LOCATION 和 SET FILE FORMAT

ALTER TABLE SET 命令还可以用于更改现有表的文件位置和文件格式。

如果表已缓存,则 ALTER TABLE .. SET LOCATION 命令会清除表及其所有引用它的依赖项的缓存数据。下次访问该表或依赖项时,缓存将被延迟填充。

语法
-- Changing File Format
ALTER TABLE table_identifier [ partition_spec ] SET FILEFORMAT file_format

-- Changing File Location
ALTER TABLE table_identifier [ partition_spec ] SET LOCATION 'new_location'

参数

RECOVER PARTITIONS

ALTER TABLE RECOVER PARTITIONS 语句用于恢复表目录中的所有分区并更新 Hive 元存储。另一种恢复分区的方法是使用 MSCK REPAIR TABLE

语法

ALTER TABLE table_identifier RECOVER PARTITIONS

参数

示例

-- RENAME table 
DESC student;
+-----------------------+---------+-------+
|               col_name|data_type|comment|
+-----------------------+---------+-------+
|                   name|   string|   NULL|
|                 rollno|      int|   NULL|
|                    age|      int|   NULL|
|# Partition Information|         |       |
|             # col_name|data_type|comment|
|                    age|      int|   NULL|
+-----------------------+---------+-------+

ALTER TABLE Student RENAME TO StudentInfo;

-- After Renaming the table
DESC StudentInfo;
+-----------------------+---------+-------+
|               col_name|data_type|comment|
+-----------------------+---------+-------+
|                   name|   string|   NULL|
|                 rollno|      int|   NULL|
|                    age|      int|   NULL|
|# Partition Information|         |       |
|             # col_name|data_type|comment|
|                    age|      int|   NULL|
+-----------------------+---------+-------+

-- RENAME partition

SHOW PARTITIONS StudentInfo;
+---------+
|partition|
+---------+
|   age=10|
|   age=11|
|   age=12|
+---------+

ALTER TABLE default.StudentInfo PARTITION (age='10') RENAME TO PARTITION (age='15');

-- After renaming Partition
SHOW PARTITIONS StudentInfo;
+---------+
|partition|
+---------+
|   age=11|
|   age=12|
|   age=15|
+---------+

-- Add new columns to a table
DESC StudentInfo;
+-----------------------+---------+-------+
|               col_name|data_type|comment|
+-----------------------+---------+-------+
|                   name|   string|   NULL|
|                 rollno|      int|   NULL|
|                    age|      int|   NULL|
|# Partition Information|         |       |
|             # col_name|data_type|comment|
|                    age|      int|   NULL|
+-----------------------+---------+-------+

ALTER TABLE StudentInfo ADD columns (LastName string, DOB timestamp);

-- After Adding New columns to the table
DESC StudentInfo;
+-----------------------+---------+-------+
|               col_name|data_type|comment|
+-----------------------+---------+-------+
|                   name|   string|   NULL|
|                 rollno|      int|   NULL|
|               LastName|   string|   NULL|
|                    DOB|timestamp|   NULL|
|                    age|      int|   NULL|
|# Partition Information|         |       |
|             # col_name|data_type|comment|
|                    age|      int|   NULL|
+-----------------------+---------+-------+

-- Drop columns of a table
DESC StudentInfo;
+-----------------------+---------+-------+
|               col_name|data_type|comment|
+-----------------------+---------+-------+
|                   name|   string|   NULL|
|                 rollno|      int|   NULL|
|               LastName|   string|   NULL|
|                    DOB|timestamp|   NULL|
|                    age|      int|   NULL|
|# Partition Information|         |       |
|             # col_name|data_type|comment|
|                    age|      int|   NULL|
+-----------------------+---------+-------+

ALTER TABLE StudentInfo DROP columns (LastName, DOB);

-- After dropping columns of the table
DESC StudentInfo;
+-----------------------+---------+-------+
|               col_name|data_type|comment|
+-----------------------+---------+-------+
|                   name|   string|   NULL|
|                 rollno|      int|   NULL|
|                    age|      int|   NULL|
|# Partition Information|         |       |
|             # col_name|data_type|comment|
|                    age|      int|   NULL|
+-----------------------+---------+-------+

-- Rename a column of a table
DESC StudentInfo;
+-----------------------+---------+-------+
|               col_name|data_type|comment|
+-----------------------+---------+-------+
|                   name|   string|   NULL|
|                 rollno|      int|   NULL|
|                    age|      int|   NULL|
|# Partition Information|         |       |
|             # col_name|data_type|comment|
|                    age|      int|   NULL|
+-----------------------+---------+-------+

ALTER TABLE StudentInfo RENAME COLUMN name TO FirstName;

-- After renaming a column of the table
DESC StudentInfo;
+-----------------------+---------+-------+
|               col_name|data_type|comment|
+-----------------------+---------+-------+
|              FirstName|   string|   NULL|
|                 rollno|      int|   NULL|
|                    age|      int|   NULL|
|# Partition Information|         |       |
|             # col_name|data_type|comment|
|                    age|      int|   NULL|
+-----------------------+---------+-------+

-- ALTER OR CHANGE COLUMNS
DESC StudentInfo;
+-----------------------+---------+-------+
|               col_name|data_type|comment|
+-----------------------+---------+-------+
|              FirstName|   string|   NULL|
|                 rollno|      int|   NULL|
|                    age|      int|   NULL|
|# Partition Information|         |       |
|             # col_name|data_type|comment|
|                    age|      int|   NULL|
+-----------------------+---------+-------+

ALTER TABLE StudentInfo ALTER COLUMN FirstName COMMENT "new comment";

-- After ALTER or CHANGE COLUMNS
DESC StudentInfo;
+-----------------------+---------+-----------+
|               col_name|data_type|    comment|
+-----------------------+---------+-----------+
|              FirstName|   string|new comment|
|                 rollno|      int|       NULL|
|                    age|      int|       NULL|
|# Partition Information|         |           |
|             # col_name|data_type|    comment|
|                    age|      int|       NULL|
+-----------------------+---------+-----------+

-- REPLACE COLUMNS
DESC StudentInfo;
+-----------------------+---------+-----------+
|               col_name|data_type|    comment|
+-----------------------+---------+-----------+
|              FirstName|   string|new comment|
|                 rollno|      int|       NULL|
|                    age|      int|       NULL|
|# Partition Information|         |           |
|             # col_name|data_type|    comment|
|                    age|      int|       NULL|
+-----------------------+---------+-----------+

ALTER TABLE StudentInfo REPLACE COLUMNS (name string, ID int COMMENT 'new comment');

-- After replacing COLUMNS
DESC StudentInfo;
+-----=---------+---------+-----------+
|       col_name|data_type|    comment|
+---------------+---------+-----------+
|           name|   string|       NULL|
|             ID|      int|new comment|
| # Partitioning|         |           |
|Not partitioned|         |           |
+---------------+---------+-----------+

-- Add a new partition to a table 
SHOW PARTITIONS StudentInfo;
+---------+
|partition|
+---------+
|   age=11|
|   age=12|
|   age=15|
+---------+

ALTER TABLE StudentInfo ADD IF NOT EXISTS PARTITION (age=18);

-- After adding a new partition to the table
SHOW PARTITIONS StudentInfo;
+---------+
|partition|
+---------+
|   age=11|
|   age=12|
|   age=15|
|   age=18|
+---------+

-- Drop a partition from the table 
SHOW PARTITIONS StudentInfo;
+---------+
|partition|
+---------+
|   age=11|
|   age=12|
|   age=15|
|   age=18|
+---------+

ALTER TABLE StudentInfo DROP IF EXISTS PARTITION (age=18);

-- After dropping the partition of the table
SHOW PARTITIONS StudentInfo;
+---------+
|partition|
+---------+
|   age=11|
|   age=12|
|   age=15|
+---------+

-- Adding multiple partitions to the table
SHOW PARTITIONS StudentInfo;
+---------+
|partition|
+---------+
|   age=11|
|   age=12|
|   age=15|
+---------+

ALTER TABLE StudentInfo ADD IF NOT EXISTS PARTITION (age=18) PARTITION (age=20);

-- After adding multiple partitions to the table
SHOW PARTITIONS StudentInfo;
+---------+
|partition|
+---------+
|   age=11|
|   age=12|
|   age=15|
|   age=18|
|   age=20|
+---------+

-- Change the fileformat
ALTER TABLE loc_orc SET fileformat orc;

ALTER TABLE p1 partition (month=2, day=2) SET fileformat parquet;

-- Change the file Location
ALTER TABLE dbx.tab1 PARTITION (a='1', b='2') SET LOCATION '/path/to/part/ways'

-- SET SERDE/ SERDE Properties
ALTER TABLE test_tab SET SERDE 'org.apache.hadoop.hive.serde2.columnar.LazyBinaryColumnarSerDe';

ALTER TABLE dbx.tab1 SET SERDE 'org.apache.hadoop' WITH SERDEPROPERTIES ('k' = 'v', 'kay' = 'vee')

-- SET TABLE PROPERTIES
ALTER TABLE dbx.tab1 SET TBLPROPERTIES ('winner' = 'loser');

-- SET TABLE COMMENT Using SET PROPERTIES
ALTER TABLE dbx.tab1 SET TBLPROPERTIES ('comment' = 'A table comment.');

-- Alter TABLE COMMENT Using SET PROPERTIES
ALTER TABLE dbx.tab1 SET TBLPROPERTIES ('comment' = 'This is a new comment.');

-- DROP TABLE PROPERTIES
ALTER TABLE dbx.tab1 UNSET TBLPROPERTIES ('winner');

-- RECOVER PARTITIONS
ALTER TABLE dbx.tab1 RECOVER PARTITIONS;