ALTER TABLE

Function

ALTER TABLE is used to modify tables, including modifying table definitions, renaming tables, renaming specified columns in tables, renaming table constraints, setting table schemas, enabling or disabling row-level access control, and adding or updating multiple columns.

Precautions

Syntax

Parameter Description

Table Operation Examples

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
DROP TABLE IF EXISTS CUSTOMER;
CREATE TABLE CUSTOMER
(    
    C_CUSTKEY     BIGINT       , 
    C_NAME        VARCHAR(25)  , 
    C_ADDRESS     VARCHAR(40)  , 
    C_NATIONKEY   INT          , 
    C_PHONE       CHAR(15)     , 
    C_ACCTBAL     DECIMAL(15,2)
)
DISTRIBUTE BY HASH(C_CUSTKEY);

Adds primary key constraint or unique constraint based on the unique index.

Create an index CUSTOMER_constraint1 for the table CUSTOMER. Then add primary key constraints, and rename the created index.

1
2
CREATE UNIQUE INDEX CUSTOMER_constraint1 ON CUSTOMER(C_CUSTKEY);
ALTER TABLE CUSTOMER ADD CONSTRAINT CUSTOMER_constraint2 PRIMARY KEY USING INDEX CUSTOMER_constraint1;

Rename a table constraint:

1
ALTER TABLE CUSTOMER RENAME CONSTRAINT CUSTOMER_constraint2 TO CUSTOMER_constraint;

Delete a table constraint:

1
ALTER TABLE CUSTOMER DROP CONSTRAINT CUSTOMER_constraint;

Add a table index:

1
ALTER TABLE CUSTOMER ADD INDEX CUSTOMER_index(C_CUSTKEY);

Delete a table index:

1
2
ALTER TABLE CUSTOMER DROP INDEX CUSTOMER_index;
ALTER TABLE CUSTOMER DROP KEY CUSTOMER_index;

Add an index to a column in the table:

1
ALTER TABLE CUSTOMER ADD c_address_id varchar(20) CONSTRAINT ca_address_index CHECK (c_address_id > 0);

Add a primary key constraint to the table:

1
ALTER TABLE CUSTOMER ADD PRIMARY KEY(C_CUSTKEY);

Rename a table:

1
ALTER TABLE CUSTOMER RENAME TO CUSTOMER_t;

Create a column-store table:

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
DROP TABLE IF EXISTS customer_address;
CREATE TABLE customer_address
(
    ca_address_sk       INTEGER                  NOT NULL   ,
    ca_address_id       CHARACTER(16)            NOT NULL   ,
    ca_street_number    CHARACTER(10)                       ,
    ca_street_name      CHARACTER varying(60)               ,
    ca_street_type      CHARACTER(15)                       ,
    ca_suite_number     CHARACTER(10)                    
)
WITH (ORIENTATION = COLUMN, COMPRESSION=HIGH,COLVERSION=2.0)
DISTRIBUTE BY HASH (ca_address_sk);

Add a partial cluster key to a column-store table:

1
ALTER TABLE customer_address ADD CONSTRAINT customer_address_cluster PARTIAL CLUSTER KEY(ca_address_sk);

Delete a partial cluster key from the column-store table.

1
ALTER TABLE customer_address DROP CONSTRAINT customer_address_cluster;

Switch the storage format of a column-store table:

1
ALTER TABLE customer_address SET (COLVERSION = 1.0);

Change the distribution mode of a table:

1
ALTER TABLE customer_address DISTRIBUTE BY REPLICATION;
Change the schema of a table:
1
2
CREATE SCHEMA tpcds;
ALTER TABLE customer_address SET SCHEMA tpcds;

Change the data temperature for a single table:

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
DROP TABLE IF EXISTS cold_hot_table;
CREATE TABLE cold_hot_table(
    W_WAREHOUSE_ID            CHAR(16)              NOT NULL,
    W_WAREHOUSE_NAME          VARCHAR(20)                   ,
    W_STREET_NUMBER           CHAR(10)                      ,
    W_STREET_NAME             VARCHAR(60)                   ,
    W_STREET_ID               CHAR(15)                      ,
    W_SUITE_NUMBER            CHAR(10)                      )
WITH (ORIENTATION = COLUMN, storage_policy = 'LMT:30')
DISTRIBUTE BY HASH (W_WAREHOUSE_ID)
PARTITION BY RANGE(W_STREET_ID)(
    PARTITION P1 VALUES LESS THAN(100000),
    PARTITION P2 VALUES LESS THAN(200000),
    PARTITION P3 VALUES LESS THAN(300000),
    PARTITION P4 VALUES LESS THAN(MAXVALUE)
)ENABLE ROW MOVEMENT;

ALTER TABLE cold_hot_table REFRESH STORAGE;

Change a column-store partitioned table to a hot and cold table.

1
2
3
4
5
6
7
CREATE table test_1(id int,d_time date)
WITH(ORIENTATION=COLUMN)
DISTRIBUTE BY HASH (id)
PARTITION BY RANGE (d_time)
(PARTITION p1 START('2022-01-01') END('2022-01-31') EVERY(interval '1 day'));

ALTER TABLE test_1 SET (storage_policy = 'LMT:100');

Column Operation Examples

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
DROP TABLE IF EXISTS warehouse_t;
CREATE TABLE warehouse_t
(
    W_WAREHOUSE_SK            INTEGER                NOT NULL,
    W_WAREHOUSE_ID            CHAR(16)               NOT NULL,
    W_WAREHOUSE_NAME          VARCHAR(20)   UNIQUE DEFERRABLE,
    W_WAREHOUSE_SQ_FT         INTEGER                        ,
    W_COUNTY                  VARCHAR(30)                    ,
    W_STATE                   CHAR(2)            DEFAULT 'GA',
    W_ZIP                     CHAR(10)                       
);

Add a column to a table:

1
ALTER TABLE warehouse_t ADD W_GOODS_CATEGORY int;

Modify the column name and column field information in the table:

1
ALTER TABLE warehouse_t CHANGE W_GOODS_CATEGORY W_GOODS_CATEGORY2 DECIMAL NOT NULL COMMENT 'W_GOODS_CATEGORY';

Add a primary key to a table:

1
ALTER TABLE warehouse_t ADD PRIMARY KEY(w_warehouse_name);

Rename a column:

1
ALTER TABLE warehouse_t RENAME W_ZIP TO new_W_ZIP;

Add columns to a table:

1
ALTER TABLE warehouse_t ADD (W_COMMENT VARCHAR(117) NOT NULL, W_COUNT int);

Change the data type of a column in the table and set the column constraint to NOT NULL:

1
ALTER TABLE warehouse_t MODIFY W_WAREHOUSE_SQ_FT varchar(20) NOT NULL;

Add the NOT NULL constraint to a certain column in the table:

1
ALTER TABLE warehouse_t ALTER COLUMN W_COUNTY SET NOT NULL;

Delete a column from a table:

1
ALTER TABLE warehouse_t DROP COLUMN W_STATE;

Helpful Links

CREATE TABLE, 12.101-RENAME TABLE, and DROP TABLE