ALTER TABLE

2024-06-28 05:30:30  Updated

Purpose

You can use this statement to modify the structure of an existing table. For example, you can use this statement to modify a table and its attributes, add columns to it, modify its columns and attributes, and drop its columns.

Syntax

alter_table_stmt:
    ALTER TABLE table_name alter_table_action_list;

alter_table_action_list:
    alter_table_action [, alter_table_action ...]

alter_table_action:
      ADD [COLUMN] column_definition  
          [ opt_position_column ]
    | ADD [COLUMN] (column_definition_list)
    | ADD [CONSTRAINT [constraint_name]] UNIQUE {INDEX | KEY}
          [index_name] index_desc
    | ADD [CONSTRAINT [constraint_name]] FOREIGN KEY
          [index_name] index_desc
          REFERENCES reference_definition
          [match_action][opt_reference_option_list]
    | ADD PRIMARY KEY (column_name)
    | ADD CONSTRAINT [constraint_name] CHECK (expression)[[NOT] ENFORCED]
    | ADD PARTITION (range_partition_list)
    | ADD {INDEX | KEY} [index_name] [index_type] (key_part,...) [index_option_list][index_column_group_option]
    | ADD COLUMN GROUP([all columns, ]each column)
    | ALTER [COLUMN] column_name {
          SET DEFAULT const_value
        | DROP DEFAULT
      }
    | ALTER {CHECK | CONSTRAINT} symbol [NOT] ENFORCED
    | ALTER INDEX index_name
          [VISIBLE | INVISIBLE]
    | CHANGE [COLUMN] column_name column_definition
    | DROP [COLUMN] column_name
    | DROP {PARTITION | SUBPARTITION} partition_name_list
    | DROP TABLEGROUP
    | DROP FOREIGN KEY fk_name
    | DROP PRIMARY KEY [, ADD PRIMARY KEY (column)]
    | DROP CHECK constraint_name
    | DROP COLUMN GROUP([all columns, ]each column)
    | MODIFY [COLUMN] column_definition
    | RENAME COLUMN old_col_name TO new_col_name
    | RENAME [TO] table_name
    | RENAME {INDEX | KEY} old_index_name TO new_index_name
    | [SET] table_option_list
    | TRUNCATE {PARTITION | SUBPARTITION} partition_name_list
    | EXCHANGE PARTITION partition_name WITH TABLE non_partition_table_name WITHOUT VALIDATION

column_definition_list:
    column_definition [, column_definition ...]

column_definition:
    column_name data_type
    [DEFAULT const_value] [AUTO_INCREMENT]
    [NULL | NOT NULL] [[PRIMARY] KEY] [UNIQUE [KEY]] [COMMENT string_value] [SKIP_INDEX(skip_index_option_list)] [ opt_position_column ]

skip_index_option_list:
    skip_index_option [,skip_index_option ...]

skip_index_option:
    MIN_MAX
    | SUM

opt_position_column:
    FIRST | BEFORE | AFTER column_name

index_desc:
   (column_desc_list) [index_type] [index_option_list]

match_action:
   MATCH {SIMPLE | FULL | PARTIAL}

opt_reference_option_list:
   reference_option [,reference_option ...]

reference_option:
   ON {DELETE | UPDATE} {RESTRICT | CASCADE | SET NULL | NO ACTION | SET DEFAULT}

column_desc_list:
    column_desc [, column_desc ...]

column_desc:
     column_name [(length)] [ASC | DESC]

key_part:
    {index_col_name [(length)] | (expr)} [ASC | DESC]

index_type:
    USING BTREE

index_option_list:
    index_option [ index_option ...]

index_option:
     [GLOBAL | LOCAL]
    | block_size
    | compression
    | STORING(column_name_list)
    | COMMENT string_value

index_column_group_option:
    WITH COLUMN GROUP([all columns, ]each column)

table_option_list:
    table_option [ table_option ...]

table_option:
      TABLEGROUP = tablegroup_name
    | block_size
    |lob_inrow_threshold [=] num
    | compression
    | AUTO_INCREMENT [=] INT_VALUE
    | COMMENT string_value
    | parallel_clause

parallel_clause:
    {NOPARALLEL | PARALLEL integer}

partition_option:
      PARTITION BY HASH(expression)
      [subpartition_option] PARTITIONS partition_count
    | PARTITION BY KEY([column_name_list])
      [subpartition_option] PARTITIONS partition_count
    | PARTITION BY RANGE {(expression) | COLUMNS (column_name_list)}
      [subpartition_option] (range_partition_list)

subpartition_option:
      SUBPARTITION BY HASH(expression)
      SUBPARTITIONS subpartition_count
    | SUBPARTITION BY KEY(column_name_list)
      SUBPARTITIONS subpartition_count
    | SUBPARTITION BY RANGE {(expression) | COLUMNS (column_name_list)}
      (range_subpartition_list)

range_partition_list:
    range_partition [, range_partition ...]

range_partition:
    PARTITION partition_name
    VALUES LESS THAN {(expression_list) | MAXVALUE}

range_subpartition_list:
    range_subpartition [, range_subpartition ...]

range_subpartition:
    SUBPARTITION subpartition_name
    VALUES LESS THAN {(expression_list) | MAXVALUE}

expression_list:
    expression [, expression ...]

column_name_list:
    column_name [, column_name ...]

partition_name_list:
    partition_name [, partition_name ...]

partition_count | subpartition_count:
    INT_VALUE

Parameters

Parameter Description
ADD [COLUMN] Adds a column. You can add a generated column.
[FIRST | BEFORE | AFTER column_name] Specifies the added column as the first column of the table or to be after the column_name column. Currently, OceanBase Database allows you to specify the position of a column only in the ADD COLUMN syntax.
CHANGE [COLUMN] Changes the column name and definition. You can increase the column length only for specific character data types, such as VARCHAR, VARBINARY, and CHAR.
MODIFY [COLUMN] Modifies the column attribute.
ALTER [COLUMN] {SET DEFAULT const_value | DROP DEFAULT} Changes the default value of a column.
DROP [COLUMN] Drops a column. You cannot drop a primary key column or columns that contain indexes.
ADD FOREIGN KEY Adds a foreign key. If you do not specify the name of the foreign key, it will be named in the format of table name + OBFK + time when the foreign key was created. For example, the foreign key created for table t1 at 00:00:00 on August 1, 2021 is named as t1_OBFK_1627747200000000. A foreign key enables one table (child table) to reference data from another table (parent table). When an UPDATE or DELETE operation affects a key value in the parent table that has matching rows in the child table, the result depends on the referential action specified in the ON UPDATE or ON DELETE clause. Valid referential actions:
  • CASCADE: deletes or updates the affected row in the parent table and automatically deletes or updates the matching rows in the child table.
  • SET NULL: deletes or updates the affected row in the parent table and sets the foreign key column in the child table to NULL.
  • RESTRICT: rejects the delete or update operation on the parent table.
  • NO ACTION: defers the check.
The SET DEFAULT action is also supported.
ADD PRIMARY KEY Adds a primary key. You can specify one or more columns as the primary key. If you specify multiple columns, they will form a composite primary key.
ALTER INDEX Modifies whether an index is visible. When the status of an index is INVISIBLE, the SQL optimizer will not select this index.
key_part Creates a normal or function-based index.
index_col_name The column name of the index. You can add ASC (ascending order) to the end of each column name. DESC (descending order) is not supported. By default, the columns are sorted in ascending order. Index-based sorting method: Data is first sorted by the values in the first column of index_col_name and by the values in the next column for the records with the same values in the first column.
expr A valid function-based index expression. A Boolean expression, such as c1=c1, is allowed.
Notice: You cannot create a function-based index on a generated column in the current version of OceanBase Database.
ADD [PARTITION] Adds a partition to a partitioned table.
DROP {PARTITION | SUBPARTITION} Drops a partition. Valid values:
  • PARTITION: drops the specified RANGE or LIST partitions and all subpartitions that exist under these partitions, including partition definitions and partition data, and maintains the indexes on the partitions.
  • SUBPARTITION: drops the specified *-RANGE or *-LIST subpartitions, including the subpartition definitions and subpartition data, and maintains the indexes on the subpartitions.
Separate multiple partition names with commas (,).
Notice: Before you drop a partition, ensure that no active transactions or queries exist in this partition. Otherwise, SQL statement errors or exceptions may occur.
TRUNCATE {PARTITION | SUBPARTITION} Truncates a partition. Valid values:
  • PARTITION: deletes all data in the specified RANGE or LIST partitions, as well as data in all subpartitions that exist under these partitions, and maintains the indexes on the partitions.
  • SUBPARTITION: deletes all data in the specified *-RANGE or *-LIST subpartitions, and maintains the indexes on the subpartitions.
Separate multiple partition names with commas (,).
Notice: Before you delete partition data, ensure that no active transactions or queries exist in this partition. Otherwise, SQL statement errors or exceptions may occur.
RENAME COLUMN old_col_name TO new_col_name Renames a column. Only the column name is changed. The column definition is not changed.

Notice

  • If the new column name already exists in the table, an error is reported.
  • However, you can swap names through a cycle, for example, ALTER TABLE t1 RENAME COLUMN a to b, RENAME COLUMN b to a;.
  • If the renamed column has an index or FOREIGN KEY constraint, RENAME COLUMN can be executed normally, and the change cascades to the index definition and FOREIGN KEY constraint.
  • An ALTER TABLE statement cannot contain any combination of RENAME COLUMN, ADD PARTITION, and ALTER COLUMN.

RENAME [TO] table_name Renames a table.
RENAME {INDEX | KEY} Renames an index or a key.
DROP [TABLEGROUP] Drops a table group.
DROP [FOREIGN KEY] Drops a foreign key.
DROP [PRIMARY KEY] Drops a primary key.

Note

In OceanBase Database, you cannot drop a primary key from a MySQL tenant in the following conditions:

  • The table is a parent table whose primary key is referenced by a foreign key column of a child table.
  • The table is a child table, but its primary key contains a foreign key column.

[SET] table_option Sets table attributes. The following parameters are supported:
  • REPLICA_NUM: sets the number of replicas of the table (not supported).
  • tablegroup_name: sets the group to which the table belongs.
  • BLOCK_SIZE: sets the microblock size of the table. Default Value: 16384, which is 16 KB. Value range: [1024,1048576].
  • lob_inrow_threshold: sets the INROW threshold. LOB data sized greater than this threshold is stored in OUTROW mode in the LOB meta table. The default value is 4KB.
  • COMPRESSION: sets the compression mode of the table. The default value is None, which means that data is not compressed.
  • AUTO_INCREMENT: sets the next value of the auto-increment column in the table.
  • comment: sets the comments for the table.
  • PROGRESSIVE_MERGE_NUM: sets the number of progressive compaction steps. Value range: [0,100].
  • parallel_clause: specifies the degree of parallelism (DOP) at the table level.
  • NOPARALLEL: sets the DOP to 1, which is the default value.
  • PARALLEL integer: sets the DOP to an integer greater than or equal to 1.
CHECK Modifies the CHECK constraint. The following operations are supported:
  • Add a new CHECK constraint.
  • Drop the current CHECK constraint named constraint_name.
[NOT] ENFORCED Specifies whether to forcibly apply the CHECK constraint named constraint_name.
  • If you do not specify this parameter or set it to ENFORCED, a CHECK constraint is created and forcibly applied. The default value is ENFORCED.
  • If you set it to NOT ENFORCED, a CHECK constraint is created but not forcibly applied.
ADD COLUMN GROUP([all columns,]each column) Converts a table into a columnstore table. The following options are supported:
  • ADD COLUMN GROUP(all columns, each column): converts the table into a rowstore-columnstore redundant table.
  • ADD COLUMN GROUP(each column): converts the table into a columnstore table.
DROP COLUMN GROUP([all columns,]each column) Removes the storage format of the table. The following options are supported:
  • DROP COLUMN GROUP(all columns, each column): removes the rowstore-columnstore redundancy format for the table.
  • DROP COLUMN GROUP(all columns): removes the rowstore format for the table.
  • DROP COLUMN GROUP(each column): removes the columnstore format for the table.
index_column_group_option Specifies the index options. The following options are supported:
  • WITH COLUMN GROUP(all columns, each column): adds a rowstore-columnstore redundant index.
  • WITH COLUMN GROUP(all columns): adds a rowstore index.
  • WITH COLUMN GROUP(each column): adds a columnstore index.
SKIP_INDEX Modifies the skip index attribute of a column. Valid values:
  • MIN_MAX: the most common skip index type. A skip index of this type stores the maximum value, minimum value, and null count of the indexed column at the index node granularity. This type of skip indexes can accelerate the pushdown of filters and MIN/MAX aggregation.
  • SUM: the skip index type that is used to accelerate the pushdown of SUM aggregation for numeric values.

Notice

  • You cannot create a skip index for a JSON column or a spatial column.
  • You cannot create a skip index for a generated column.

EXCHANGE PARTITION partition_name WITH TABLE non_partition_table_name Exchanges a specified table partition with a table. Here, partition_name specifies the name of a partition in a partitioned table for the exchange. non_partition_table_name specifies the name of a non-partitioned table for the exchange. For more information about exchanging partitions, see Exchange partitions.

Examples

Add and drop columns

Create a table named tbl1 and execute the DESCRIBE statement to view the table information.

obclient> CREATE TABLE tbl1 (c1 INT(11) PRIMARY KEY,c2 VARCHAR(50));
Query OK, 0 rows affected

obclient> DESCRIBE tbl1;
+-------+------------+----------+--------+---------+-------+
| Field | Type       | Null     | Key    | Default | Extra |
+-------+------------+----------+--------+---------+-------+
| c1    | int(11)    | NO       | PRI    | NULL    |       |    
| c2    | varchar(50)| YES      |        | NULL    |       |   
+-------+------------+----------+--------+---------+-------+
  • Add a column named c3 and execute the DESCRIBE statement to view the table information.

    obclient> ALTER TABLE tbl1 ADD c3 INT;
    Query OK, 1 row affected
    
    obclient> DESCRIBE tbl1;
    +-------+------------+----------+--------+---------+-------+
    | Field | Type       | Null     | Key    | Default | Extra |
    +-------+------------+----------+--------+---------+-------+
    | c1    | int(11)    | NO       | PRI    | NULL    |       |    
    | c2    | varchar(50)| YES      |        | NULL    |       |  
    | c3    | int(11)    | YES      |        | NULL    |       |  
    +-------+------------+----------+--------+---------+-------+
    3 row affected
    
  • Drop the c3 column and execute the DESCRIBE statement to view the table information.

    obclient> ALTER TABLE tbl1 DROP c3;
    Query OK, 1 row affected
    
    obclient> DESCRIBE tbl1;
    +-------+------------+----------+--------+---------+-------+
    | Field | Type       | Null     | Key    | Default | Extra |
    +-------+------------+----------+--------+---------+-------+
    | c1    | int(11)    | NO       | PRI    | NULL    |       |    
    | c2    | varchar(50)| YES      |        | NULL    |       |  
    +-------+------------+----------+--------+---------+-------+
    2 row affected
    
  • Rename the c2 column in the tbl1 table to c3 and execute the DESCRIBE statement to view the table information.

    obclient> ALTER TABLE tbl1 CHANGE COLUMN c2 c3 VARCHAR(50);
    Query OK, 1 row affected
    
    obclient> DESCRIBE tbl1;
    +-------+------------+----------+--------+---------+-------+
    | Field | Type       | Null     | Key    | Default | Extra |
    +-------+------------+----------+--------+---------+-------+
    | c1    | int(11)    | NO       | PRI    | NULL    |       |    
    | c3    | varchar(50)| YES      |        | NULL    |       |  
    +-------+------------+----------+--------+---------+-------+
    2 rows affected
    
  • Add a column named c4 to the tbl1 table, set this column as the first column of the table, and execute the DESCRIBE statement to view the table information.

    obclient> ALTER TABLE tbl1 ADD COLUMN c4 INTEGER FIRST;
    Query OK, 1 row affected
    
    obclient> DESCRIBE tbl1;
    +-------+------------+----------+--------+---------+-------+
    | Field | Type       | Null     | Key    | Default | Extra |
    +-------+------------+----------+--------+---------+-------+
    | c4    | int(11)    | YES      |        | NULL    |       |  
    | c1    | int(11)    | NO       | PRI    | NULL    |       |    
    | c3    | varchar(50)| YES      |        | NULL    |       |  
    +-------+------------+----------+--------+---------+-------+
    3 row affected
    
  • Add a column named c2 behind the c1 column and execute the DESCRIBE statement to view the table information.

    obclient> ALTER TABLE tbl1 ADD COLUMN c2 INTEGER AFTER c1;
    Query OK, 1 row affected
    
    obclient> DESCRIBE tbl1;
    +-------+------------+----------+--------+---------+-------+
    | Field | Type       | Null     | Key    | Default | Extra |
    +-------+------------+----------+--------+---------+-------+
    | c4    | int(11)    | YES      |        | NULL    |       |  
    | c1    | int(11)    | NO       | PRI    | NULL    |       |
    | c2    | int(11)    | YES      |        | NULL    |       |    
    | c3    | varchar(50)| YES      |        | NULL    |       |  
    +-------+------------+----------+--------+---------+-------+
    4 row affected
    
  • Add a column named c5 before the c4 column and execute the DESCRIBE statement to view the table information.

    obclient> ALTER TABLE tbl1 ADD COLUMN c5 INT BEFORE c4;
    Query OK, 1 row affected
    
    obclient> DESCRIBE tbl1;
    +-------+------------+----------+--------+---------+-------+
    | Field | Type       | Null     | Key    | Default | Extra |
    +-------+------------+----------+--------+---------+-------+
    | c5    | int(11)    | YES      |        | NULL    |       |  
    | c4    | int(11)    | YES      |        | NULL    |       |  
    | c1    | int(11)    | NO       | PRI    | NULL    |       |
    | c2    | int(11)    | YES      |        | NULL    |       |    
    | c3    | varchar(50)| YES      |        | NULL    |       |  
    +-------+------------+----------+--------+---------+-------+
    5 row affected
    
  • Add a FOREIGN KEY constraint fk1 to the tbl2 table. Specify to execute the SET NULL action when an UPDATE operation affects a key value in the parent table that has matching rows in the child table.

    obclient> CREATE TABLE tbl2(c1 INT PRIMARY KEY,c2 INT);
    Query OK, 0 row affected
    obclient> CREATE TABLE tbl3(c1 INT PRIMARY KEY,c2 INT);
    Query OK, 0 row affected
    obclient> ALTER TABLE tbl2 ADD CONSTRAINT fk1 FOREIGN KEY (c2) REFERENCES tbl3(c1) ON UPDATE SET NULL;
    Query OK, 0 row affected
    
  • Drop the FOREIGN KEY constraint fk1 from the tbl3 table.

    obclient> ALTER TABLE tbl2 DROP FOREIGN KEY fk1;
    Query OK, 0 row affected
    
  • Drop the primary key of the tbl2 table.

    obclient> ALTER TABLE tbl2 DROP PRIMARY KEY;
    Query OK, 0 row affected
    

Index operations

  • Rename the ind1 index on the tbl2 table to ind2.

    obclient> CREATE TABLE tbl2(c1 INT(11) PRIMARY KEY,c2 INT(50));
    Query OK, 0 row affected
    
    obclient> CREATE INDEX ind1 ON tbl2 (c2 ASC);
    Query OK, 0 row affected
    obclient> ALTER TABLE tbl2 RENAME INDEX ind1 TO ind2;
    Query OK, 0 row affected
    
  • Create an index named ind3 on the tbl2 table to reference the c1 and c2 columns.

    obclient> ALTER TABLE tbl2 ADD INDEX ind3 (c1,c2);
    Query OK, 0 row affected
    

    You can execute the SHOW INDEX statement to view the created indexes.

    obclient> SHOW INDEX FROM tbl2;
    +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+
    | Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment   | Index_comment | Visible |
    +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+
    | tbl2  |          0 | PRIMARY  |            1 | c1          | A         |        NULL | NULL     | NULL   |      | BTREE      | available |               | YES     |
    | tbl2  |          1 | ind2     |            1 | c2          | A         |        NULL | NULL     | NULL   |  YES | BTREE      | available |               | YES     |
    | tbl2  |          1 | ind3     |            1 | c1          | A         |        NULL | NULL     | NULL   |      | BTREE      | available |               | YES     |
    | tbl2  |          1 | ind3     |            2 | c2          | A         |        NULL | NULL     | NULL   |  YES | BTREE      | available |               | YES     |
    +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+
    4 rows in set
    
  • Drop the ind2 index from the tbl2 table.

    obclient> ALTER TABLE tbl2 DROP INDEX ind2;
    Query OK, 0 row affected
    

    Note

    You can use the preceding method to implement an atomic change to an index in actual O&M scenarios.

  • Add three function-based indexes to t1_func, name one index as i2, and use system-generated names in the format of a sequence number prefixed with functional_index for the other two indexes.

    obclient> ALTER TABLE t1_func ADD INDEX ((CONCAT(c1,'a')));
    Query OK, 0 rows affected
    obclient> ALTER TABLE t1_func ADD INDEX ((c1+1));
    Query OK, 0 rows affected
    obclient> ALTER TABLE t1_func ADD INDEX i2 ((CONCAT(c1,'a')));
    Query OK, 0 rows affected
    obclient> SHOW CREATE TABLE t1_func;
    +---------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
    | Table   | Create Table                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                  |
    +---------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
    | t1_func | CREATE TABLE `t1_func` (
    `c1` int(11) DEFAULT NULL,
    `c2` int(11) DEFAULT NULL,
    KEY `i1` (((`c1` + `c2`) < 1)) BLOCK_SIZE 16384 LOCAL,
    KEY `functional_index` (concat(`c1`,'a')) BLOCK_SIZE 16384 LOCAL,
    KEY `functional_index_2` ((`c1` + 1)) BLOCK_SIZE 16384 LOCAL,
    KEY `i2` (concat(`c1`,'a')) BLOCK_SIZE 16384 LOCAL
    ) DEFAULT CHARSET = utf8mb4 ROW_FORMAT = DYNAMIC COMPRESSION = 'zstd_1.3.8' REPLICA_NUM = 1 BLOCK_SIZE = 16384 USE_BLOOM_FILTER = FALSE TABLET_SIZE = 134217728 PCTFREE = 0 |
    +---------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
    1 row in set
    
  • Create a columnstore index for a table.

    1. Create a table named tbl3.

      CREATE TABLE tbl3 (col1 INT, col2 VARCHAR(50));
      
    2. On the tbl3 table, create a columnstore index named idx1_tbl3 that references the col1 column.

      ALTER TABLE tbl3 ADD INDEX idx1_tbl3 (col1) WITH COLUMN GROUP(each column);
      

Partition operations

  • Truncate partitions M202001 and M202002 of the t_log_part_by_range table.

    obclient> CREATE TABLE t_log_part_by_range (
        log_id      bigint NOT NULL
        , log_value varchar(50)
        , log_date  timestamp NOT NULL  
    ) PARTITION BY RANGE(UNIX_TIMESTAMP(log_date))
    (
        PARTITION M202001 VALUES LESS THAN(UNIX_TIMESTAMP('2020/02/01'))
        , PARTITION M202002 VALUES LESS THAN(UNIX_TIMESTAMP('2020/03/01'))
        , PARTITION M202003 VALUES LESS THAN(UNIX_TIMESTAMP('2020/04/01'))
        , PARTITION M202004 VALUES LESS THAN(UNIX_TIMESTAMP('2020/05/01'))
        , PARTITION M202005 VALUES LESS THAN(UNIX_TIMESTAMP('2020/06/01'))
    );
    Query OK, 0 rows affected
    
    obclient> ALTER TABLE t_log_part_by_range TRUNCATE PARTITION M202001, M202002;
    Query OK, 0 rows affected
    
  • Add the M202006 partition to the t_log_part_by_range table.

    obclient> CREATE TABLE t_log_part_by_range (
        log_id      bigint NOT NULL
        , log_value varchar(50)
        , log_date  timestamp NOT NULL  
    ) PARTITION BY RANGE(UNIX_TIMESTAMP(log_date))
    (
        PARTITION M202001 VALUES LESS THAN(UNIX_TIMESTAMP('2020/02/01'))
        , PARTITION M202002 VALUES LESS THAN(UNIX_TIMESTAMP('2020/03/01'))
        , PARTITION M202003 VALUES LESS THAN(UNIX_TIMESTAMP('2020/04/01'))
        , PARTITION M202004 VALUES LESS THAN(UNIX_TIMESTAMP('2020/05/01'))
        , PARTITION M202005 VALUES LESS THAN(UNIX_TIMESTAMP('2020/06/01'))
    );
    Query OK, 0 rows affected
    
    obclient> ALTER TABLE t_log_part_by_range ADD PARTITION
             (PARTITION M202006 VALUES LESS THAN(UNIX_TIMESTAMP('2020/07/01'))
             );
    

Change the DOP

  • Change the DOP of the tbl3 table to 2.

    obclient> ALTER TABLE tbl3 PARALLEL 2;
    
  • Change the ordinary column col1 of the tbl4 table to an auto-increment column.

    obclient> CREATE TABLE tbl4 (col1 BIGINT(10) NOT NULL,col2 INT);
    Query OK, 0 rows affected
    
    obclient> ALTER TABLE tbl4 MODIFY col1 BIGINT(10) AUTO_INCREMENT;
    Query OK, 0 rows affected
    
  • Add the primary key column col1 to the tbl4 table, and then change the primary key to col2.

    obclient> ALTER TABLE tbl4 ADD PRIMARY KEY (col1);
    Query OK, 0 rows affected
    
    obclient> ALTER TABLE tbl4 DROP PRIMARY KEY,ADD PRIMARY KEY (`col2`);
    Query OK, 0 rows affected
    
  • Add a CHECK constraint.

    obclient> CREATE TABLE tbl7(col1 VARCHAR(10),col2 VARCHAR(10));
    Query OK, 0 rows affected
    
    obclient> ALTER TABLE tbl7 ADD CONSTRAINT my_check CHECK (col1> col2) ;
    Query OK, 0 rows affected
    
  • Drop the CHECK constraint from the tbl7 table.

    obclient> ALTER TABLE tbl7 DROP CHECK my_check;
    Query OK, 0 rows affected
    
  • Change the column type to NOT NULL.

    obclient> CREATE TABLE dept(  
        deptno           NUMBER(2,0),  
        dname            VARCHAR(14),  
        location         VARCHAR(13),   
        CONSTRAINT pk_dept PRIMARY KEY(deptno)  
    );
    Query OK, 0 rows affected
    
    obclient> CREATE TABLE emp(  
        empno         NUMBER(4,0) NOT NULL,  
        empname       VARCHAR(10) NOT NULL,  
        job           VARCHAR(9) NOT NULL,  
        mgr           NUMBER(4,0) NOT NULL,  
        hiredate      DATE NOT NULL,  
        sal           NUMBER(7,2) DEFAULT NULL,
        comm          NUMBER(7,2) DEFAULT NULL,        
        deptno        NUMBER(2,0) DEFAULT NULL,   
        CONSTRAINT PK_emp PRIMARY KEY (empno),
        CONSTRAINT FK_deptno  FOREIGN KEY (deptno)  REFERENCES dept (deptno)  
    );
    Query OK, 0 rows affected
    
    obclient> ALTER TABLE emp MODIFY deptno NUMBER(2,0) DEFAULT '12' NOT NULL;
    Query OK, 0 rows affected
    

Rename a column

  • RENAME COLUMN only changes the column name and does not change the column definition. If the new column name already exists in the table, an error is reported when RENAME COLUMN is executed. However, no error is reported when the old and new column names are the same.

    obclient> CREATE TABLE tbl8 (a INT, b INT);
    Query OK, 0 rows affected
    
    obclient> ALTER TABLE tbl8 RENAME COLUMN a TO b;
    ERROR 1060 (42S21): Duplicate column name 'b'
    
    obclient> ALTER TABLE tbl8 RENAME COLUMN a TO a;
    Query OK, 0 rows affected
    
  • If the renamed column has an index, RENAME COLUMN can be executed normally, and the change cascades to the index definition.

    obclient> CREATE TABLE tbl9 (a INT, b INT, index idx_a(a));
    Query OK, 0 rows affected
    
    obclient> SHOW INDEX FROM tbl9;
    +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
    | Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment   | Index_comment | Visible | Expression |
    +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
    | tbl9  |          1 | idx_a    |            1 | a           | A         |        NULL | NULL     | NULL   | YES  | BTREE      | available |               | YES     | NULL       |
    +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
    1 row in set
    
    obclient> ALTER TABLE tbl9 RENAME COLUMN a TO c;
    Query OK, 0 rows affected
    
    obclient> SHOW INDEX FROM tbl9;
    +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
    | Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment   | Index_comment | Visible | Expression |
    +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
    | tbl9  |          1 | idx_a    |            1 | c           | A         |        NULL | NULL     | NULL   | YES  | BTREE      | available |               | YES     | NULL       |
    +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
    1 row in set
    
  • If the renamed column is referenced by a prefix index, RENAME COLUMN can be executed normally, and the change cascades to the prefix index.

    DROP TABLE tbl9;
    obclient> CREATE TABLE tbl9 (c1 INT PRIMARY KEY, c2 BLOB, c3 INT, INDEX i1 (c2(10)));
    Query OK, 0 rows affected
    
    obclient> ALTER TABLE tbl9 RENAME COLUMN c2 TO c2_, RENAME COLUMN c1 TO c2_1;
    DESC tbl9;
    Query OK, 0 rows affected
    
    obclient> SHOW INDEX FROM tbl9;
    +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
    | Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment   | Index_comment | Visible | Expression |
    +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
    | tbl9  |          0 | PRIMARY  |            1 | c2_1        | A         |        NULL | NULL     | NULL   |      | BTREE      | available |               | YES     | NULL       |
    | tbl9  |          1 | i1       |            1 | c2_         | A         |        NULL | 10       | NULL   | YES  | BTREE      | available |               | YES     | NULL       |
    +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
    2 rows in set
    
  • If the renamed column has a FOREIGN KEY constraint, RENAME COLUMN can be executed normally, and the change cascades to the FOREIGN KEY constraint.

    obclient> CREATE TABLE tbl10 (a INT PRIMARY KEY);
    Query OK, 0 rows affected
    
    obclient> CREATE TABLE tbl11(b INT, FOREIGN KEY (b) REFERENCES tbl10(a));
    
    obclient> SHOW CREATE TABLE tbl11;
    +-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
    | Table | Create Table                                                                                                                                                                                                                                                                                                                                                      |
    +-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
    | tbl11 | CREATE TABLE `tbl11` (
    `b` int(11) DEFAULT NULL,
    CONSTRAINT `tbl11_OBFK_1694681944513338` FOREIGN KEY (`b`) REFERENCES `test`.`tbl10`(`a`) ON UPDATE RESTRICT ON DELETE RESTRICT
    ) DEFAULT CHARSET = utf8mb4 ROW_FORMAT = DYNAMIC COMPRESSION = 'zstd_1.3.8' REPLICA_NUM = 1 BLOCK_SIZE =  16384 USE_BLOOM_FILTER = FALSE TABLET_SIZE = 134217728 PCTFREE = 0 |
    +-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
    1 row in set
    
    obclient> ALTER TABLE tbl10 RENAME COLUMN a TO c;
    Query OK, 0 rows affected
    
    obclient> SHOW CREATE TABLE tbl11;
    +-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
    | Table | Create Table                                                                                                                                                                                                                                                                                                                                                      |
    +-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
    | tbl11 | CREATE TABLE `tbl11` (
    `b` int(11) DEFAULT NULL,
    CONSTRAINT `tbl11_OBFK_1694681944513338` FOREIGN KEY (`b`) REFERENCES `test`.`tbl10`(`c`) ON UPDATE RESTRICT ON DELETE RESTRICT
    ) DEFAULT CHARSET = utf8mb4 ROW_FORMAT = DYNAMIC COMPRESSION = 'zstd_1.3.8' REPLICA_NUM = 1 BLOCK_SIZE = 16384 USE_BLOOM_FILTER = FALSE TABLET_SIZE = 134217728 PCTFREE = 0 |
    +-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
    1 row in set
    

OceanBase Database does not support change or cascading change in the following scenarios:

  • The renamed column is referenced by a column generation expression. In this case, an error is reported when you execute RENAME COLUMN.

    obclient> CREATE TABLE tbl12(a INT, b INT AS (a + 1), c INT, d INT, CONSTRAINT d_check CHECK(d > 0)) PARTITION BY HASH(c + 1) PARTITIONS 2;
    
    obclient> ALTER TABLE tbl12 RENAME COLUMN a TO e;
    ERROR 3108 (HY000): Column 'a' has a generated column dependency
    
  • The renamed column is referenced by a partition expression. In this case, an error is reported when you execute RENAME COLUMN.

    obclient> ALTER TABLE tbl12 RENAME COLUMN c TO e;
    ERROR 3855 (HY000): Column 'c' has a partitioning function dependency and cannot be dropped or renamed.
    
  • The renamed column is referenced by a CHECK constraint. In this case, an error is reported when you execute RENAME COLUMN.

    obclient> ALTER TABLE tbl12 RENAME COLUMN d TO e;
    ERROR 3959 (HY000): Check constraint 'd_check' uses column 'd', hence column cannot be dropped or renamed.
    
  • The renamed column is referenced by a function-based index. In this case, an error is reported when you execute RENAME COLUMN.

    DROP TABLE IF EXISTS tbl12;
    obclient> CREATE TABLE tbl12(i INT, INDEX ((i+1)));
    Query OK, 0 rows affected
    
    obclient> ALTER TABLE tbl12 RENAME COLUMN i TO j;
    ERROR 3837 (HY000): Column 'i' has a functional index dependency and cannot be dropped or renamed.
    
  • The renamed column is referenced by a view. In this case, you can successfully execute RENAME COLUMN, but an error is reported for queries on the view. To solve this problem, you must manually modify the view definition.

    obclient> CREATE TABLE tbl13(a INT);
    Query OK, 0 rows affected
    
    obclient> CREATE VIEW v1 AS SELECT a + 1 FROM tbl13;
    Query OK, 0 rows affected
    
    obclient> SELECT * FROM v1;
    Empty set
    
    obclient> ALTER TABLE tbl13 RENAME COLUMN a TO b;
    Query OK, 0 rows affected
    
    obclient> SELECT * FROM v1;
    ERROR 1356 (42S22): View 'test.v1' references invalid table(s) or column(s) or function(s) or definer/invoker of view lack rights to use them
    
  • The renamed column is referenced by a stored procedure. In this case, you can successfully execute RENAME COLUMN, but an error is reported when the procedure is called. To solve this problem, you must manually modify the stored procedure.

    obclient> CREATE TABLE tbl14(a INT);
    Query OK, 0 rows affected
    
    obclient> CREATE PROCEDURE proc() SELECT a + 1 FROM tbl14;
    Query OK, 0 rows affected
    
    obclient> CALL proc();
    Empty set
    
    obclient> ALTER TABLE tbl14 RENAME COLUMN a TO b;
    Query OK, 0 rows affected
    
    obclient> CALL proc();
    ERROR 1054 (42S22): Unknown column 'a' in 'field list'
    

Modify the columnstore attribute of a table

  1. Create a table named tbl1.

    CREATE TABLE tbl1 (col1 INT PRIMARY KEY, col2 VARCHAR(50));
    
  2. Convert the tbl1 table into a rowstore-columnstore redundant table, and then drop the rowstore-columnstore redundancy attribute.

    ALTER TABLE tbl1 ADD COLUMN GROUP(all columns, each column);
    
    ALTER TABLE tbl1 DROP COLUMN GROUP(all columns, each column);
    
  3. Convert the tbl1 table into a columnstore table, and then drop the columnstore attribute.

    ALTER TABLE tbl1 ADD COLUMN GROUP(each column);
    
    ALTER TABLE tbl1 DROP COLUMN GROUP(each column);
    

Modify the skip index attribute of a column

Use the following SQL statement to create a table named test_skidx.

CREATE TABLE test_skidx(
  col1 INT SKIP_INDEX(MIN_MAX, SUM),
  col2 FLOAT SKIP_INDEX(MIN_MAX),
  col3 VARCHAR(1024) SKIP_INDEX(MIN_MAX),
  col4 CHAR(10)
  );
  • Change the type of the skip index on the col2 column in the test_skidx table to SUM.

    ALTER TABLE test_skidx MODIFY COLUMN col2 FLOAT SKIP_INDEX(SUM);
    
  • Add the skip index attribute for a column after the table is created.

    Add a skip index of the MIN_MAX type for the col4 column in the test_skidx table.

    ALTER TABLE test_skidx MODIFY COLUMN col4 CHAR(10) SKIP_INDEX(MIN_MAX);
    
  • Delete the skip index attribute for a column after the table is created.

    Delete the skip index attribute of the col1 column in the test_skidx table.

    ALTER TABLE test_skidx MODIFY COLUMN col1 INT SKIP_INDEX();
    

    or

    ALTER TABLE test_skidx MODIFY COLUMN col1 INT;
    

References

Modify a table

Contact Us