OceanBase v4.2.1特性解读: MySQL租户rename column语法支持

2024年 5月 6日 58.8k 0

1. 背景描述

MySQL从8.0开始支持rename column语法,方便用户在不改变列定义的前提下为列重新命名。以下是一个rename column的使用示例:

alter table t1 rename column col_a to col_b;

OceanBase过去的版本中,已在Oracle租户下支持了rename column语法,本次调整是在4.2.1以及往后的版本中,支持MySQL租户的rename column的语法,以兼容MySQL8.0。

2. 功能描述

rename column语法:

ALTER TABLE tbl_name [rename_action [, rename_action] ...];

rename_action: RENAME old_col_name To new_col_name;

rename column不改变列定义,仅修改列名。如果目标名称在表中已经存在,那么rename column执行会报错:

OceanBase(root@test)>create table t1 (a int, b int);
Query OK, 0 rows affected (0.100 sec)

OceanBase(root@test)>alter table t1 rename column a to b;
ERROR 1060 (42S21): Duplicate column name 'b'

不过也有例外,如果重命名的列出现了循环,可以正常执行。比如下面的是一个合法的alter示例:

OceanBase(root@test)>create table t1 (a int, b int);
Query OK, 0 rows affected (0.046 sec)

OceanBase(root@test)>alter table t1 rename column a to b, rename column b to a;
Query OK, 0 rows affected (0.076 sec)

OceanBase(root@test)>desc t1;
+-------+---------+------+-----+---------+-------+
| Field | Type    | Null | Key | Default | Extra |
+-------+---------+------+-----+---------+-------+
| b     | int(11) | YES  |     | NULL    |       |
| a     | int(11) | YES  |     | NULL    |       |
+-------+---------+------+-----+---------+-------+
2 rows in set (0.003 sec)

如果重命名的列上建有索引,或者有外键约束,rename column可以正常执行,并且索引定义和外键约束会自动级联联修改,比如:

OceanBase(root@test)>create table t1 (a int, b int, index idx_a(a));
Query OK, 0 rows affected (0.057 sec)

OceanBase(root@test)>show index from t1;
+-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
| Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment   | Index_comment | Visible | Expression |
+-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
| t1    |          1 | idx_a    |            1 | a           | A         |        NULL | NULL     | NULL   | YES  | BTREE      | available |               | YES     | NULL       |
+-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
1 row in set (0.014 sec)

OceanBase(root@test)>alter table t1 rename column a to c;
Query OK, 0 rows affected (0.058 sec)

OceanBase(root@test)>show index from t1;
+-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
| Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment   | Index_comment | Visible | Expression |
+-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
| t1    |          1 | idx_a    |            1 | c           | A         |        NULL | NULL     | NULL   | YES  | BTREE      | available |               | YES     | NULL       |
+-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+-----------+---------------+---------+------------+
OceanBase(root@test)>create table t1 (a int primary key);
Query OK, 0 rows affected (0.043 sec)

OceanBase(root@test)>create table t2(b int, foreign key (b) references t1(a));
Query OK, 0 rows affected (0.066 sec)

OceanBase(root@test)>show create table t2;
+-------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Table | Create Table                                                                                                                                                                                                                                                                                                                                             |
+-------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| t2    | CREATE TABLE `t2` (
  `b` int(11) DEFAULT NULL,
  CONSTRAINT `t2_OBFK_1691379783330957` FOREIGN KEY (`b`) REFERENCES `test`.`t1`(`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 (0.019 sec)

OceanBase(root@test)>alter table t1 rename column a to b;
Query OK, 0 rows affected (0.053 sec)

OceanBase(root@test)>show create table t2;
+-------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Table | Create Table                                                                                                                                                                                                                                                                                                                                             |
+-------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| t2    | CREATE TABLE `t2` (
  `b` int(11) DEFAULT NULL,
  CONSTRAINT `t2_OBFK_1691379783330957` FOREIGN KEY (`b`) REFERENCES `test`.`t1`(`b`) 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 (0.009 sec)

但是在以下场景,并不会自动级联修改:

  1. 重命名的列被生成列表达式引用,执行会报错,不支持修改。
  2. 重命名的列被分区表达式引用,执行报错,不支持修改。
  3. 重命名的列被check约束引用,执行报错,不支持修改。
  4. 重命名的列被视图引用,rename column执行成功,查询视图报错,需要用户手动修改视图定义。
  5. 重命名的列被存储过程引用,rename column执行成功,call procedure报错,需要用户手动修改。
OceanBase(root@test)>create table t1(a int, b int as (a + 1), c int, d int, constraint d_check check(d > 0)) partition by hash(c + 1) partitions 2;
Query OK, 0 rows affected (0.057 sec)

OceanBase(root@test)>alter table t1 rename column a to e;
ERROR 3108 (HY000): Column 'a' has a generated column dependency
OceanBase(root@test)>alter table t1 rename column c to e;
ERROR 3855 (HY000): Column 'c' has a partitioning function dependency and cannot be dropped or renamed.
OceanBase(root@test)>alter table t1 rename column d to e;
ERROR 3959 (HY000): Check constraint 'd_check' uses column 'd', hence column cannot be dropped or renamed.
OceanBase(root@test)>create table t1 (a int);
Query OK, 0 rows affected (0.043 sec)

OceanBase(root@test)>create view v1 as select a + 1 from t1;
Query OK, 0 rows affected (0.040 sec)

OceanBase(root@test)>create procedure p() select a + 1 from t1;
Query OK, 0 rows affected (0.036 sec)

OceanBase(root@test)>select * from v1;
Empty set (0.010 sec)

OceanBase(root@test)>call p();
Empty set (0.014 sec)

Query OK, 0 rows affected (0.014 sec)

OceanBase(root@test)>alter table t1 rename column a to b;
Query OK, 0 rows affected (0.053 sec)

OceanBase(root@test)>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
OceanBase(root@test)>call p();
ERROR 1054 (42S22): Unknown column 'a' in 'field list'

3. 限制以及注意事项

第一:MySQL 8.0规定ADD PARTITION, DROP PARTITION, DISCARD PARTITION, IMPORT PARTITION, COALESCE PARTITION, REORGANIZE PARTITION, EXCHANGE PARTITION, ANALYZE PARTITION, CHECK PARTITIONREPAIR PARTITION 操作不能和rename column语句一起使用,比如下面一个add partition的例子,执行会报语法错误:

mysql> create table t1 (a int, b int) partition by range(a) (partition p0 values less than (10));
Query OK, 0 rows affected (0.01 sec)

mysql> alter table t1 rename column b to c, add partition (partition p1 values less than (20));
ERROR 1064 (42000): You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'partition (partition p1 values less than (20))' at line 1

对于同一条alter stmt中同时包含alter_partition_action和alter_column_action的场景,OB当前的实现选择了执行报错(NOT SUPPORTED错误),比如上述SQL:

OceanBase(root@test)>create table t1 (a int, b int) partition by range(a) (partition p0 values less than (10));
Query OK, 0 rows affected (0.052 sec)

OceanBase(root@test)>alter table t1 rename column b to c, add partition (partition p1 values less than (20));
ERROR 1235 (0A000): specify alter_column_action and alter_partition_action in a single alter table stmt not supported

第二:MySQL 8.0支持在同一条alter stmt中指定drop column和rename column,如果rename的目标列名和drop的列名相同,rename column可以执行成功,比如:

mysql> create table t1(a int, b int);
Query OK, 0 rows affected (0.01 sec)

mysql> alter table t1 drop column a, rename column b to a;
Query OK, 0 rows affected (0.01 sec)
Records: 0  Duplicates: 0  Warnings: 0

OB目前不支持上述两个alter_column_action在一次DDL中执行:

OceanBase(root@test)>create table t1 (a int, b int);
Query OK, 0 rows affected (0.047 sec)

OceanBase(root@test)>alter table t1 drop column a, rename column b to a;
ERROR 1060 (42S21): Duplicate column name 'a'

建议再drop column和rename column拆成两个DDL语句执行分别执行。

相关文章

Oracle如何使用授予和撤销权限的语法和示例
Awesome Project: 探索 MatrixOrigin 云原生分布式数据库
下载丨66页PDF,云和恩墨技术通讯(2024年7月刊)
社区版oceanbase安装
Oracle 导出CSV工具-sqluldr2
ETL数据集成丨快速将MySQL数据迁移至Doris数据库

发布评论