After you create a table, you can use the INSERT statement or other statements to insert data into the table. This topic describes how to insert data into a table by using statements.
Prerequisites
Before you insert data into a table, make sure that:
You have logged on to a MySQL tenant of OceanBase Database. For more information about how to connect to OceanBase Database, see Connection methods.
Note
You can query the
oceanbase.DBA_OB_TENANTSview in thesystenant to confirm the mode of the tenant to which you have logged on.You have the
INSERTprivilege on the target table. For more information about how to view your privileges, see View user privileges. If you do not have the required privileges, contact the administrator. For more information, see Modify user privileges.
Use an INSERT statement to insert data
Use the INSERT statement to insert data into a table based on the following suggestions.
The syntax is as follows:
INSERT INTO table_name (list_of_columns) VALUES (list_of_values);
| Parameter | Required | Description |
|---|---|---|
| table_name | Yes | The table into which data is to be inserted. |
| (list_of_columns) | No | The table columns into which data is to be inserted. |
| (list_of_values) | Yes | The values of the columns specified by list_of_columns. The values and the columns must be in one-to-one mapping. |
Suggestions on data insertion
Before you insert data, we recommend that you learn the information about all columns of the table, including the column types, valid values, and whether
NULLvalues are allowed.You can use the
DESCstatement to query information about columns.obclient [test]> DESC test; +-------+---------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +-------+---------+------+-----+---------+-------+ | col1 | int(11) | NO | | NULL | | | col2 | int(11) | YES | | NULL | | +-------+---------+------+-----+---------+-------+ 2 rows in setFor a
NOT NULLcolumn, note that:If the column has a default value, you do not need to specify a value for this column when you insert data. The system will insert the default value into this column if you do not specify a value.
If no default value has been specified for the column, you must specify a value for the column when you insert data.
For a
NULLcolumn, you do not need to specify a value for this column when you insert data. The system will insert aNULLvalue into this column.
Before you insert data into a table, we recommend that you learn the information about constraints defined on columns of the table. This is to avoid errors when you insert data.
You can query the
NOT NULL,PRIMARY KEY, andUNIQUEconstraints by using theDESCstatement. You can query theFOREIGN KEYandCHECKconstraints in theinformation_schema.TABLE_CONSTRAINTSview.
Insert a single row of data
You can use the INSERT statement to insert a single row of data. To insert multiple records, you can execute the single-row insertion statement multiple times. To perform batch insertion, see Insert multiple rows of data in batches.
Assume that the information about the table into which data is to be inserted is as follows:
obclient [test]> CREATE TABLE t_insert(
id int NOT NULL PRIMARY KEY,
name varchar(10) NOT NULL,
value int,
gmt_create DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP
);
Query OK, 0 rows affected
The id and name columns of the table cannot be empty. The id column is the primary key column with a UNIQUE constraint, and therefore cannot have duplicate values. A default value is specified for the gmt_create column.
Example 1: Insert multiple rows of data into a table by executing the single-row insertion statement multiple times.
A default value is specified for the gmt_create column. Therefore, you do not need to specify a value for this column when you insert data.
obclient [test]> INSERT INTO t_insert(id, name, value)
VALUES (1,'CN',10001);
Query OK, 2 rows affected
obclient [test]> INSERT INTO t_insert(id, name, value)
VALUES(2,'US', 10002);
Query OK, 2 rows affected
If no default value is specified for the gmt_create column, you must specify a value for this column when you insert data by using the following statement:
obclient [test]> INSERT INTO t_insert(id, name, value, gmt_create)
VALUES (3,'EN', 10003, current_timestamp ());
Query OK, 1 row affected
Insert multiple rows of data in batches
To insert multiple records, you can also use an INSERT statement that contains multiple VALUES. A single multi-row insertion statement is executed faster than multiple single-row insertion statements.
The operation in Example 1 can be completed by using the statement in Example 2.
Example 2: Insert multiple rows of data in batches.
obclient [test]> INSERT INTO t_insert(id, name, value)
VALUES (1,'CN',10001),(2,'US', 10002);
Query OK, 2 rows affected
To back up a table or copy all records in a table to another table, you can use the INSERT INTO ... SELECT ... FROM statement as the VALUES clause in the INSERT statement for batch insertion.
Example 3: Back up all data in the t_insert table to the t_insert_bak table.
obclient [test]> SELECT * FROM t_insert;
+----+------+-------+---------------------+
| id | name | value | gmt_create |
+----+------+-------+---------------------+
| 1 | CN | 10001 | 2022-10-12 15:17:17 |
| 2 | US | 10002 | 2022-10-12 16:29:16 |
| 3 | EN | 10003 | 2022-10-12 16:29:26 |
+----+------+-------+---------------------+
3 rows in set
obclient [test]> CREATE TABLE t_insert_bak(
id number NOT NULL PRIMARY KEY,
name varchar(10) NOT NULL,
value number,
gmt_create DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP
);
Query OK, 0 rows affected
obclient [test]> INSERT INTO t_insert_bak SELECT * FROM t_insert;
Query OK, 2 rows affected
obclient [test]> SELECT * FROM t_insert_bak;
+----+------+-------+---------------------+
| id | name | value | gmt_create |
+----+------+-------+---------------------+
| 1 | CN | 10001 | 2022-10-12 15:17:17 |
| 2 | US | 10002 | 2022-10-12 16:29:16 |
| 3 | EN | 10003 | 2022-10-12 16:29:26 |
+----+------+-------+---------------------+
3 rows in set
Avoid UNIQUE constraint conflicts
When you insert identical records into a table that has a UNIQUE constraint, the database returns an error. Here is the error message:
obclient [test]> INSERT INTO t_insert(id, name, value) VALUES (3,'UK', 10003),(4, 'JP', 10004);
ERROR 1062 (23000): Duplicate entry '3' for key 'PRIMARY'
You can use the INSERT IGNORE INTO or INSERT INTO ON DUPLICATE KEY UPDATE statement to avoid this error.
Here is an example:
If you use
INSERT IGNORE INTOto avoid constraint conflicts, you can use theIGNOREkeyword to ignore the impact of an insertion failure caused by a constraint conflict.obclient [test]> INSERT IGNORE INTO t_insert(id, name, value) VALUES (3,'UK', 10003),(4, 'JP', 10004); Query OK, 1 row affected obclient [test]> SELECT * FROM t_insert; +----+------+-------+---------------------+ | id | name | value | gmt_create | +----+------+-------+---------------------+ | 1 | CN | 10001 | 2022-10-12 15:17:17 | | 2 | US | 10002 | 2022-10-12 16:29:16 | | 3 | EN | 10003 | 2022-10-12 16:29:26 | | 4 | JP | 10004 | 2022-10-12 17:02:52 | +----+------+-------+---------------------+ 4 rows in setIn this example, the
INSERT IGNORE INTOstatement is used. Therefore, the system does not return an error even if(3,'UK', 10003)failed to be inserted.Notice
This method ignores only the error data but does not affect the insert operation.
If you use
INSERT INTO ON DUPLICATE KEY UPDATEto avoid constraint conflicts, you can specify the action to take on duplicate primary keys or unique keys.Note
ON DUPLICATE KEY UPDATE column_name = expris specified: If the data to be inserted is duplicate with values of the primary key or unique key, you can use thecolumn_name = exprstatement to update the data in conflicting rows of the table. Thecolumn_name = exprstatement can assign values to one or more columns of the conflicting rows. Separate the columns with commas (,).ON DUPLICATE KEY UPDATE column_name = expris not specified: If the data to be inserted is duplicate with values of the primary key or unique key, the system returns an error.
obclient [test]> INSERT INTO t_insert(id, name, value) VALUES (3,'UK', 10003),(5, 'CN', 10005) ON DUPLICATE KEY UPDATE name = VALUES(name); Query OK, 1 row affected obclient [test]> SELECT * FROM t_insert; +----+------+-------+---------------------+ | id | name | value | gmt_create | +----+------+-------+---------------------+ | 1 | CN | 10001 | 2022-10-12 16:29:16 | | 2 | US | 10002 | 2022-10-12 15:17:17 | | 3 | UK | 10003 | 2022-10-12 16:29:26 | | 4 | JP | 10004 | 2022-10-12 17:02:52 | | 5 | CN | 10005 | 2022-10-12 17:27:46 | +----+------+-------+---------------------+ 5 rows in setIn this example,
ON DUPLICATE KEY UPDATE name = VALUES(name)specifies that when the inserted data is duplicate with a value of the primary key, the value of thenamecolumn of the conflicting row(3,'EN', 10003)in the original data is updated to the value of thenamecolumn of the data to be inserted. For non-conflicting rows, data is normally inserted.
Insert data by using other statements
Besides the INSERT statement, you can use the REPLACE INTO statement instead to insert data into a table without data records or a table with data records but no conflicts with the primary key or unique key constraints. For more information about the REPLACE INTO statement, see REPLACE.
Here are the examples:
Create a table named
t_replaceand then use theREPLACE INTOstatement to insert data into the table.obclient [test]> CREATE TABLE t_replace( id int NOT NULL PRIMARY KEY , name varchar(10) NOT NULL , value int ,gmt_create timestamp NOT NULL DEFAULT current_timestamp ); Query OK, 0 rows affected obclient [test]> REPLACE INTO t_replace VALUES(1,'CN',2001, current_timestamp ()); Query OK, 1 row affected obclient [test]> SELECT * FROM t_replace; +----+------+-------+---------------------+ | id | name | value | gmt_create | +----+------+-------+---------------------+ | 1 | CN | 2001 | 2022-11-23 09:52:44 | +----+------+-------+---------------------+ 1 row in setUse the
REPLACE INTOstatement to insert data into thet_replacetable that has data records.obclient [test]> SELECT * FROM t_replace; +----+------+-------+---------------------+ | id | name | value | gmt_create | +----+------+-------+---------------------+ | 1 | CN | 2001 | 2022-03-22 16:13:55 | +----+------+-------+---------------------+ 1 row in set obclient [test]> REPLACE INTO t_replace values(2,'US',2002, current_timestamp ()); Query OK, 1 row affected obclient [test]> SELECT * FROM t_replace; +----+------+-------+---------------------+ | id | name | value | gmt_create | +----+------+-------+---------------------+ | 1 | CN | 2001 | 2022-11-23 09:52:44 | | 2 | US | 2002 | 2022-11-23 09:53:05 | +----+------+-------+---------------------+ 2 rows in set