DELETE =========================== 描述 ----------- 该语句用来删除表中符合条件的行,包括单表删除及多表删除两种方式。 格式 ----------- ```javascript Single-Table-Delete Syntax: DELETE [hint_options] FROM tbl_name [PARTITION (partition_name,...)] [WHERE where_condition] [ORDER BY order_expression_list] [LIMIT row_count] Multiple-Table-Delete Syntax: DELETE [hint_options] tbl_name[.*] [, tbl_name[.*]] ... FROM table_references [WHERE where_condition] Or: DELETE [hint_options] FROM tbl_name[.*] [, tbl_name[.*]] ... USING table_references [WHERE where_condition] where_condition: expression order_expression_list: order_expression [, order_expression ...] order_expression: expression [ASC | DESC] limit_row_count: INT_VALUE table_references: {tbl_name | joined_table | table_subquery | select_with_parens} [, ...] ``` 参数解释 ------------- | **参数** | **描述** | |-----------------------|----------------------| | hint_options | 指定hint选项。 | | tbl_name | 指定需要删除的表名。 | | partition_name | 需要删除表的对应分区名。 | | where_condition | 删除的表需要满足的过滤条件。 | | order_expression_list | 删除的表的排序键列表。 | | row_count | 删除的表的行数指定,指定的值只能为整数。 | | table_references | 多表删除时指定的待选择的表序列。 | 示例 ----------- 示例表及数据基于以下定义: ```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) ``` * 单表删除:删除 "c1=2" 的行,其中 c1 列为表 t1 中的 Primary Key。 ```javascript OceanBase(admin@test)>DELETE FROM t1 WHERE c1 = 2; Query OK, 1 row affected (0.02 sec) OceanBase(admin@test)>select * from t1; +----+------+ | c1 | c2 | +----+------+ | 1 | 1 | | 3 | 3 | | 4 | 4 | +----+------+ 3 rows in set (0.01 sec) ``` * 单表删除:删除表 t2 的按照 c2 列排序之后的第一行数据。 ```javascript OceanBase(admin@test)>DELETE FROM t1 ORDER BY c2 LIMIT 1; Query OK, 1 row affected (0.01 sec) OceanBase(admin@test)>select * from t1; +----+------+ | c1 | c2 | +----+------+ | 2 | 2 | | 3 | 3 | | 4 | 4 | +----+------+ 3 rows in set (0.00 sec) ``` * 单表删除:执行删除表 t2 的 p2 分区的数据。 ```javascript OceanBase(admin@test)>DELETE FROM t2 PARTITION(p2); Query OK, 3 rows affected (0.02 sec) OceanBase(admin@test)>select * from t2; +----+------+ | c1 | c2 | +----+------+ | 5 | 5 | +----+------+ 1 row in set (0.02 sec) ``` * 多表删除:删除 t1,t2 表中 "t1.c1 = t2.c1" 的数据。 ```javascript OceanBase(admin@test)>DELETE t1, t2 FROM t1, t2 WHERE t1.c1 = t2.c1; Query OK, 3 rows affected (0.02 sec) OceanBase(admin@test)>select * from t1; +----+------+ | c1 | c2 | +----+------+ | 4 | 4 | +----+------+ 1 row in set (0.01 sec) OceanBase(admin@test)>select * from t2; +----+------+ | c1 | c2 | +----+------+ | 5 | 5 | +----+------+ 1 row in set (0.01 sec) ``` * 多表删除:删除 t1,t2 表中 "t1.c1 = t2.c1" 的数据。 ```javascript OceanBase(admin@test)>DELETE FROM t1, t2 USING t1, t2 WHERE t1.c1 = t2.c1; Query OK, 4 rows affected (0.02 sec) OceanBase(admin@test)>select * from t1; +----+------+ | c1 | c2 | +----+------+ | 4 | 4 | +----+------+ 1 row in set (0.01 sec) OceanBase(admin@test)>select * from t2; Empty set (0.01 sec) ``` * 多表删除:删除 t2 表中的 p2 分区中和 t1 表中 "t1.c1 = t2.c1" 的数据。 ```javascript OceanBase(admin@test)>DELETE t2 FROM t1,t2 PARTITION(p2) WHERE t1.c1 = t2.c1; Query OK, 3 rows affected (0.02 sec) OceanBase(admin@test)>select * from t2; +----+------+ | c1 | c2 | +----+------+ | 5 | 5 | +----+------+ 1 row in set (0.01 sec) ``` * 对可更新视图v进行删除操作 ```javascript OceanBase(admin@test)>create view v as select * from t1; Query OK, 0 rows affected (0.07 sec) OceanBase(admin@test)>delete from v where v.c1 = 1; Query OK, 1 row affected (0.02 sec) OceanBase(admin@test)>select * from v; +----+------+ | c1 | c2 | +----+------+ | 2 | 2 | | 3 | 3 | | 4 | 4 | +----+------+ 3 rows in set (0.01 sec) ``` 注意事项 ------------- 不管是多表删除还是单表删除都不支持直接对子查询进行删除操作,比如: `delete from (select * from t1);`