Purpose
You can use this statement to modify the schema 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 table_name [alter_option [, alter_option] ...]
[partition_options]
alter_option: {
table_options
ADD [COLUMN] col_name column_definition
[FIRST | BEFORE | AFTER column_name]
| ADD [COLUMN] (col_name column_definition, ...)
| ADD {INDEX | KEY} [index_name]
[index_type] (key_part,...) [index_option [ index_option ...]
| 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][reference_option [,reference_option ...]]
| ADD PRIMARY KEY (column_name)
| ADD CONSTRAINT [constraint_name] CHECK (expression)[[NOT] ENFORCED]
| ADD PARTITION (range_partition [, range_partition ...])
| 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 [, partition_name ...]
| DROP TABLEGROUP
| DROP FOREIGN KEY fk_name
| DROP PRIMARY KEY [, ADD PRIMARY KEY (column)]
| DROP CHECK constraint_name
| 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 [ table_option ...]
| TRUNCATE {PARTITION | SUBPARTITION} partition_name [, partition_name ...]
| DUPLICATE_SCOPE= 'none | cluster'
column_definition:
column_name data_type
[DEFAULT const_value] [AUTO_INCREMENT]
[NULL | NOT NULL] [[PRIMARY] KEY] [UNIQUE [KEY]] comment
[[FIRST | BEFORE | AFTER column_name]]
index_desc:
(column_desc [, column_desc ...]) [index_type] [index_option [ index_option ...]]
column_desc:
column_name [(length)] [ASC | DESC]
match_action:
MATCH {SIMPLE | FULL | PARTIAL}
reference_option:
ON {DELETE | UPDATE} {RESTRICT | CASCADE | SET NULL | NO ACTION | SET DEFAULT}
key_part:
{index_col_name [(length)] | (expr)} [ASC | DESC]
index_type:
USING BTREE
index_option:
[GLOBAL | LOCAL]
| block_size
| compression
| STORING(column_name [, column_name ...])
| comment
| KEY_BLOCK_SIZE [=] INT_VALUE
table_option:
TABLEGROUP = tablegroup_name
| block_size
|lob_inrow_threshold [=] num
| compression
| AUTO_INCREMENT [=] INT_VALUE
| comment
| parallel_clause
| KEY_BLOCK_SIZE [=] INT_VALUE
| TABLE_MODE [=] 'table_mode_value'
| auto_increment_cache_size [=] INT_VALUE
parallel_clause:
{NOPARALLEL | PARALLEL integer}
table_mode_value:
NORMAL
| QUEUING
| MODERATE
| SUPER
| EXTREME
partition_options:
partition_option [partition_option] ...
partition_option:
PARTITION BY HASH(expression)
[subpartition_option] PARTITIONS partition_count
| PARTITION BY KEY([column_name [, column_name ...]])
[subpartition_option] PARTITIONS partition_count
| PARTITION BY RANGE {(expression) | COLUMNS (column_name [, column_name ...])}
[subpartition_option] (range_partition [, range_partition ...])
subpartition_option:
SUBPARTITION BY HASH(expression)
SUBPARTITIONS subpartition_count
| SUBPARTITION BY KEY(column_name [, column_name ...])
SUBPARTITIONS subpartition_count
| SUBPARTITION BY RANGE {(expression) | COLUMNS (column_name [, column_name ...])}
(range_subpartition [, range_subpartition ...])
range_partition:
PARTITION partition_name
VALUES LESS THAN {(expression [, expression ...]) | MAXVALUE}
range_subpartition:
SUBPARTITION subpartition_name
VALUES LESS THAN {(expression [, expression ...]) | MAXVALUE}
partition_count | subpartition_count:
INT_VALUE
Parameters
| Category | Parameter | Description |
|---|---|---|
| alter_option | 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 located before or after the column specified by column_name. Currently, OceanBase Database allows you to specify the position of a column only in the ADD COLUMN syntax. |
|
| ADD {INDEX | KEY} | Adds an index on the table. | |
| ADD [CONSTRAINT UNIQUE [INDEX | KEY] | Adds a UNIQUE constraint. | |
| 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 t1_OBFK_1627747200000000. A foreign key enables one table (child table) to reference data from another table (parent table). When an UPDATE or a 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:
SET DEFAULT action is also supported.
NoticeTo define a |
|
| 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. | |
| ADD [PARTITION] | Adds a partition to a partitioned table. | |
| ALTER INDEX | Specifies 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. In the current version, only the syntax of DESC (descending order) is supported, and the functionality does not take effect. By default, the columns are sorted in ascending order. The index-based sorting method is as follows: Data is first sorted by the values in the first column of the columns specified in index_col_name and by the values in the next column for the records with the same values in the first column. |
|
| CHECK | Modifies the CHECK constraint. The following operations are supported:
|
|
| expr | A valid function-based index expression. A Boolean expression, such as c1=c1, is allowed. Notice You cannot create function-based indexes on generated columns in the current version of OceanBase Database. |
|
| [NOT] ENFORCED | Specifies whether to forcibly apply the CHECK constraint with the name specified by constraint_name.
|
|
| ALTER [COLUMN] {SET DEFAULT const_value | DROP DEFAULT} | Changes the default value of a column. | |
| 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. |
|
| DROP [COLUMN] | Drops a column. You cannot drop a primary key column. | |
| DROP {PARTITION | SUBPARTITION} | Drops partitions.
Notice Before you drop a partition, make sure that no active transactions or queries exist in this partition. Otherwise, SQL statement errors or exceptions may occur. |
|
| DROP [TABLEGROUP] | Drops a table group. | |
| DROP [FOREIGN KEY] | Drops a foreign key. | |
| DROP [PRIMARY KEY] | Drops the primary key.
NoteIn OceanBase Database, you cannot drop a primary key from a MySQL tenant in the following scenarios:
|
|
| MODIFY [COLUMN] | Modifies the column attribute. | |
| 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
|
|
| RENAME [TO] table_name | Renames a table.
NoticeDuring a |
|
| RENAME {INDEX | KEY} | Renames an index or a key. | |
| [SET] table_option | Sets table attributes. The following parameters are supported:
|
|
| TRUNCATE {PARTITION | SUBPARTITION} | Truncates partitions.
Notice Before you truncate a partition, make sure that no active transactions or queries exist in this partition. Otherwise, SQL statement errors or exceptions may occur. |
|
| DUPLICATE_SCOPE | Changes the replicated table attribute. Valid values:
|
|
| index_option | KEY_BLOCK_SIZE [=] INT_VALUE | Optional. The byte size of index key blocks, which is used to control the compression level of the table or index. In the current version, only the keyword syntax is supported. The functionality does not actually take effect. |
| table_option | TABLE_MODE | Optional. The threshold for triggering a major compaction, and the major compaction strategy. This parameter defines the major compaction behavior after a minor compaction. For more information, see table_mode_value. |
| auto_increment_cache_size | The number of cached auto-increment values. The default value is 0, which means not to specify the cache size of the auto-increment column. In this case, the value of the tenant-level parameter auto_increment_cache_size is used. |
|
| partition_option | PARTITION BY {HASH(key) ...} PARTITIONS partition_count | The partitioning key, partitioning method, and number of partitions. You can repartition a table, add partitions, drop partitions, and truncate partitions. For more information, see Partition operations. |
| subpartition_option | SUBPARTITION BY {HASH(expression) ...} | The subpartitioning strategy. |
| range_partition | PARTITION partition_name VALUES LESS THAN {value} | The partition or subpartition definition in RANGE or RANGE COLUMNS partitioning. |
table_mode_value
Note
Among the listed table modes, except the NORMAL mode, all other modes represent QUEUING tables. QUEUING tables are the most basic type of tables. Except for the NORMAL mode, other table modes indicate more proactive major compaction strategies.
NORMAL: This is the default value. In this mode, the probability of triggering a major compaction after a minor compaction is extremely low.QUEUING: In this mode, the probability of triggering a major compaction after a minor compaction is low.MODERATE: In this mode, the probability of triggering a major compaction after a minor compaction is moderate.SUPER: In this mode, the probability of triggering a major compaction after a minor compaction is high.EXTREME: In this mode, the probability of triggering a major compaction after a minor compaction is very high.
For more information about major compactions, see Adaptive major compactions.
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
c3and execute theDESCRIBEstatement 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 affectedDrop the
c3column and execute theDESCRIBEstatement 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 affectedRename the
c2column in thetbl1table toc3and execute theDESCRIBEstatement 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 affectedAdd a column named
c4to thetbl1table, set this column as the first column of the table, and execute theDESCRIBEstatement 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 affectedAdd a column named
c2behind thec1column and execute theDESCRIBEstatement 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 affectedAdd a column named
c5before thec4column and execute theDESCRIBEstatement 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 affectedAdd a
FOREIGN KEYconstraint namedfk1to thetbl2table. Specify to execute theSET NULLaction when anUPDATEoperation 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 affectedDrop the
FOREIGN KEYconstraintfk1from thetbl3table.obclient> ALTER TABLE tbl2 DROP FOREIGN KEY fk1; Query OK, 0 row affectedDrop the primary key of the
tbl2table.obclient> ALTER TABLE tbl2 DROP PRIMARY KEY; Query OK, 0 row affected
Perform index operations
Rename the
ind1index on thetbl2table asind2.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 affectedCreate an index named
ind3on thetbl2table to reference thec1andc2columns.obclient> ALTER TABLE tbl2 ADD INDEX ind3 (c1,c2); Query OK, 0 row affectedYou can execute the
SHOW INDEXstatement 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 setDrop the
ind2index from thetbl2table.obclient> ALTER TABLE tbl2 DROP INDEX ind2; Query OK, 0 row affectedNote
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 the
t1_functable, name one index asi2, and use system-generated names in the format of a sequence number prefixed withfunctional_indexfor 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 setSet an index to be invisible.
Note
After an index is set to be invisible,
/*!80000 INVISIBLE */appears in the table schema.Create a table named
tbl4.CREATE TABLE tbl4 (col1 INT PRIMARY KEY, col2 INT, col3 INT);Create an index named
idx1_tbl4.CREATE INDEX idx1_tbl4 ON tbl4(col2);Set the
idx1_tbl4index to be invisible.ALTER TABLE tbl4 ALTER INDEX idx1_tbl4 INVISIBLE;Query the schema of the
tbl4table.SHOW CREATE TABLE tbl4;The return result is as follows:
+-------+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ | Table | Create Table | +-------+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ | tbl4 | CREATE TABLE `tbl4` ( `col1` int(11) NOT NULL, `col2` int(11) DEFAULT NULL, `col3` int(11) DEFAULT NULL, PRIMARY KEY (`col1`), KEY `idx1_tbl4` (`col2`) BLOCK_SIZE 16384 LOCAL /*!80000 INVISIBLE */ ) 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
Perform partition operations
Truncate the
M202001andM202002partitions of thet_log_part_by_rangepartitioned 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 affectedAdd the
M202006partition to thet_log_part_by_rangetable.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
tbl3table to2.obclient> ALTER TABLE tbl3 PARALLEL 2;
Perform operations related to column types
Change the ordinary column
col1of thetbl4table 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 affectedAdd the primary key column
col1to thetbl4table, and then change the primary key tocol2.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 affectedAdd a
CHECKconstraint.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 affectedDrop the
CHECKconstraint from thetbl7table.obclient> ALTER TABLE tbl7 DROP CHECK my_check; Query OK, 0 rows affectedChange 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 COLUMNonly 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 whenRENAME COLUMNis 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 affectedIf the column to be renamed has an index,
RENAME COLUMNcan be normally executed, 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 setIf the column to be renamed is referenced by a prefix index,
RENAME COLUMNcan be normally executed, 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 setIf the column to be renamed has a
FOREIGN KEYconstraint,RENAME COLUMNcan be normally executed, and the change cascades to theFOREIGN KEYconstraint.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 the change or cascade the change in the following scenarios:
The column to be renamed 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 dependencyThe column to be renamed 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 column to be renamed is referenced by a
CHECKconstraint. In this case, an error is reported when you executeRENAME 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 column to be renamed is referenced by a function 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 column to be renamed is referenced by a view. In this case, you can successfully execute
RENAME COLUMN, but an error will be reported for subsequent 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 themThe column to be renamed is referenced by a stored procedure. In this case, you can successfully execute
RENAME COLUMN, but an error will be 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'