INSERT =========================== 描述 ----------- 该语句用于添加一个或多个记录到表中。 格式 ----------- ```javascript INSERT [IGNORE] [INTO] single_table_insert [ON DUPLICATE KEY UPDATE update_asgn_list] single_table_insert: {dml_table_name values_clause | dml_table_name '(' ')' values_clause | dml_table_name '(' column_list ')' values_clause | dml_table_name SET update_asgn_list} dml_table_name: tbl_name [PARTITION (partition_name,...)] values_clause: {{VALUES | VALUE} ({expr | DEFAULT},...) [, ...] | select_stmt} column_list column_name [, ...] update_asgn_list: column_name = expr [, ...] ``` 参数解释 ------------- **INSERT...ON DUPLICATE KEY UPDATE...** **语句执行,affect row的计算:** * 在没有设置client_capabilities中CLIENT_FOUND_ROWS的情况下: * 如果设置了CLIENT_FOUND_ROWS: * CLIENT_FOUND_ROWS的影响在于:不设置CLIENT_FOUND_ROWS的情况下,计算affected_row的值,只计算实际更新了行数,而设置了CLIENT_FOUND_ROWS的话,会把所有touched行数(满足冲突条件的行)都记上,而不管其是否发生了真正的数据修改。 | **参数** | **描述** | |-------------------------|-----------------------------------------------------------------------------------------------------------------------------| | IGNORE | 在INSERT语句执行过程中发生的错误将会被忽略。 | | column_list | 用于指定插入数据的列,同时插入多列时,用","隔开。 | | tbl_name | 指定要插入的表名。 | | partition_name | 插入表指定的分区名。 | | update_asgn_list | 赋值语句,例如:"c1 = 2" | | ON DUPLICATE KEY UPDATE | 指定对重复主键或唯一键的处理。如果指定了ON DUPLICATE KEY UPDATE,当要插入的主键或唯一键有重复时,会用配置值替换待插入的值;如果不指定ON DUPLICATE KEY UPDATE,当要插入的主键或唯一键有重复时,插入报错。 | 示例 ----------- 示例表及数据基于以下定义: ```javascript OceanBase(admin@test)>create table t1(c1 int primary key, c2 int) partition by key(c1) partitions 4; Query OK, 0 rows affected (0.16 sec) OceanBase(admin@test)>create table t2(c1 int primary key, c2 int); Query OK, 0 rows affected (0.16 sec) OceanBase(admin@test)>select * from t2; +----+------+ | c1 | c2 | +----+------+ | 1 | 1 | | 2 | 2 | | 3 | 3 | | 4 | 4 | +----+------+ 4 rows in set (0.06 sec) ``` * 向表 t1 中插入一行数数据。 ```javascript OceanBase(admin@test)>insert into t1 values(1,1); Query OK, 1 row affected (0.01 sec) OceanBase(admin@test)>select * from t1; +----+------+ | c1 | c2 | +----+------+ | 1 | 1 | +----+------+ 1 row in set (0.04 sec) ``` * 向表 t1 中插入多行数据。 ```javascript OceanBase(admin@test)>insert t1 values(1,1),(2,default),(2+2,3*4); Query OK, 3 rows affected (0.02 sec) Records: 3 Duplicates: 0 Warnings: 0 OceanBase(admin@test)>select * from t1; +----+------+ | c1 | c2 | +----+------+ | 1 | 1 | | 2 | NULL | | 4 | 12 | +----+------+ 3 rows in set (0.02 sec) ``` * 向表 t1 指定的 p0 分区插入单行数据。 ```javascript OceanBase(admin@test)>insert into t1 partition(p0) (c1) values(5); Query OK, 1 row affected (0.02 sec) OceanBase(admin@test)>select * from t1 partition(p0); +----+------+ | c1 | c2 | +----+------+ | 5 | NULL | +----+------+ 1 row in set (0.01 sec) ``` * 将表 t2 的查询结果作为数据插入表 t1。 ```javascript OceanBase(admin@test)>insert into t1 select * from t2; Query OK, 4 rows affected (0.02 sec) Records: 4 Duplicates: 0 Warnings: 0 OceanBase(admin@test)>select * from t1; +----+------+ | c1 | c2 | +----+------+ | 1 | 1 | | 2 | 2 | | 3 | 3 | | 4 | 4 | +----+------+ 4 rows in set (0.01 sec) ``` * 向表 t1 中插入重复主键值时利用 ON DUPLICATE KEY UPDATE 功能进行值更新 ```javascript OceanBase(admin@test)>insert into t1 values(1,1),(1,2) ON DUPLICATE KEY UPDATE c1=100; Query OK, 3 rows affected (0.01 sec) Records: 2 Duplicates: 1 Warnings: 0 OceanBase(admin@test)>select * from t1; +-----+------+ | c1 | c2 | +-----+------+ | 100 | 1 | +-----+------+ 1 row in set (0.02 sec) ``` * 对可更新视图v的插入值 ```javascript OceanBase(admin@test)>create view v as select * from t1; Query OK, 0 rows affected (0.07 sec) OceanBase(admin@test)>insert into v values(1,1); Query OK, 1 row affected (0.01 sec) OceanBase(admin@test)>select * from v; +----+------+ | c1 | c2 | +----+------+ | 1 | 1 | +----+------+ 1 row in set (0.02 sec) ``` 注意事项 ------------- INSERT语句不支持直接对子查询进行插入操作,比如: `insert into (select * from t1) values(1, 1);`