UPDATE =========================== 描述 ----------- 该语句用于修改表中的字段值。 格式 ----------- ```javascript UPDATE [IGNORE] table_references SET update_asgn_list [WHERE where_condition] [ORDER BY order_list] [LIMIT row_count]; table_references: tbl_name [PARTITION (partition_name,...)] [, ...] update_asgn_list: column_name = expr [, ...] order_list: column_name [ASC|DESC] [, column_name [ASC|DESC]...] ``` 参数解释 ------------- | **参数** | **描述** | |------------------|-----------------------------| | IGNORE | 在 INSERT 语句执行过程中发生的错误将会被忽略。 | | table_references | 指定修改表名,多表修改时,表名直接','作为间隔。 | | where_condition | 指定过滤条件。 | | row_count | 限制的行数。 | | tbl_name | 插入表名。 | | partition_name | 插入表指定的分区名。 | | column_name | 列名。 | | column_name ASC | 按列名升序修改。 | | column_name DESC | 按列名降序修改。 | 注意事项 ------------- 不管是多表还是单表更新都不支持直接对子查询进行更新值操作,例如:`update (select * from t1) set c1 = 100;` 示例 ----------- 1. 创建示例表 t1 和 t2。 ```javascript OceanBase(admin@test)>create table t1(c1 int primary key, c2 int); Query OK, 0 rows affected (0.16 sec) OceanBase(admin@test)>select * from t1; +----+------+ | c1 | c2 | +----+------+ | 1 | 1 | | 2 | 2 | | 3 | 3 | | 4 | 4 | +----+------+ 4 rows in set (0.06 sec) OceanBase(admin@test)>create table t2(c1 int primary key, c2 int) partition by key(c1) partitions 4; Query OK, 0 rows affected (0.19 sec) OceanBase(admin@test)>select * from t2; +----+------+ | c1 | c2 | +----+------+ | 5 | 5 | | 1 | 1 | | 2 | 2 | | 3 | 3 | +----+------+ 4 rows in set (0.02 sec) ``` 2. 将表 t1 中 "t1.c1=1" 对应的那一行数据的 c2 列值修改为 100。 ```javascript OceanBase(admin@test)>update t1 set t1.c2 = 100 where t1.c1 = 1; Query OK, 1 row affected (0.02 sec) Rows matched: 1 Changed: 1 Warnings: 0 OceanBase(admin@test)>select * from t1; +----+------+ | c1 | c2 | +----+------+ | 1 | 100 | | 2 | 2 | | 3 | 3 | | 4 | 4 | +----+------+ 4 rows in set (0.01 sec) ``` 3. 将表 t1 中按照 c2 列排序的前两行数据的 c2 列值修改为 100。 ```javascript OceanBase(admin@test)>update t1 set t1.c2 = 100 order by c2 limit 2; Query OK, 2 rows affected (0.02 sec) Rows matched: 2 Changed: 2 Warnings: 0 OceanBase(admin@test)>select * from t1; +----+------+ | c1 | c2 | +----+------+ | 1 | 100 | | 2 | 100 | | 3 | 3 | | 4 | 4 | +----+------+ 4 rows in set (0.01 sec) ``` 4. 将表 t2 中 p2 分区的数据中 "t2.c1 \> 2" 的对应行数据的 c2 列值修改为 100。 ```javascript OceanBase(admin@test)>update t2 partition(p2) set t2.c2 = 100 where t2.c1 > 2; Query OK, 1 row affected (0.02 sec) Rows matched: 1 Changed: 1 Warnings: 0 OceanBase(admin@test)>select * from t2; +----+------+ | c1 | c2 | +----+------+ | 5 | 5 | | 1 | 1 | | 2 | 2 | | 3 | 100 | +----+------+ 4 rows in set (0.06 sec) ``` 5. 修改多个表。将 t1 表和 t2 表中满足 "t1.c1 = t2.c1" 对应行的数据 t1 表中的 c2 列值修改为 100,t2 表中的 c2 列值修改为 200。 ```javascript OceanBase(admin@test)>update t1,t2 set t1.c2 = 100, t2.c2 = 200 where t1.c2 = t2.c2; Query OK, 6 rows affected (0.03 sec) Rows matched: 6 Changed: 6 Warnings: 0 OceanBase(admin@test)>select * from t1; +----+------+ | c1 | c2 | +----+------+ | 1 | 100 | | 2 | 100 | | 3 | 100 | | 4 | 4 | +----+------+ 4 rows in set (0.00 sec) OceanBase(admin@test)>select * from t2; +----+------+ | c1 | c2 | +----+------+ | 5 | 5 | | 1 | 200 | | 2 | 200 | | 3 | 200 | +----+------+ 4 rows in set (0.01 sec) ``` 6. 修改多个表。修改 t1 表和 t2 表的p2分区中满足 "t1.c1 = t2.c1" 对应行的数据 t1 表中的 c2 列值修改为 100,t2 表中的 c2 列值修改为 200。 ```javascript OceanBase(admin@test)>update t1,t2 partition(p2) set t1.c2 = 100, t2.c2 = 200 where t1.c2 = t2.c2; Query OK, 6 rows affected (0.02 sec) Rows matched: 6 Changed: 6 Warnings: 0 OceanBase(admin@test)>select * from t1; +----+------+ | c1 | c2 | +----+------+ | 1 | 100 | | 2 | 100 | | 3 | 100 | | 4 | 4 | +----+------+ 4 rows in set (0.01 sec) OceanBase(admin@test)>select * from t2; +----+------+ | c1 | c2 | +----+------+ | 5 | 5 | | 1 | 200 | | 2 | 200 | | 3 | 200 | +----+------+ 4 rows in set (0.01 sec) ``` 7. 对可更新视图 v 进行更新值。 ```javascript OceanBase(admin@test)>create view v as select * from t1; Query OK, 0 rows affected (0.07 sec) OceanBase(admin@test)>update v set v.c2 = 100 where v.c1 = 1; Query OK, 1 row affected (0.02 sec) Rows matched: 1 Changed: 1 Warnings: 0 OceanBase(admin@test)>select * from v; +----+------+ | c1 | c2 | +----+------+ | 1 | 100 | | 2 | 2 | | 3 | 3 | | 4 | 4 | +----+------+ 4 rows in set (0.01 sec) ```