After you create a table, you can use the INSERT INTO statement or other statements to insert records into the table. This topic describes how to use related statements.
Prerequisites
Before you insert data into a table, make sure that:
You have connected to an Oracle 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 in.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 privilege, contact the administrator to obtain the privilege. For more information, see Grant direct privileges.
Use the INSERT INTO statement to insert data
You can use the INSERT INTO statement to insert data into a table.
The syntax of the INSERT INTO statement 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 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 null values are allowed.
You can use the
DESCstatement to query information about columns.obclient [SYS]> DESC ordr; +-------+--------------+------+-----+---------+-------+ | FIELD | TYPE | NULL | KEY | DEFAULT | EXTRA | +-------+--------------+------+-----+---------+-------+ | C1 | NUMBER | YES | NULL | NULL | NULL | | C2 | VARCHAR2(50) | YES | NULL | NULL | NULL | +-------+--------------+------+-----+---------+-------+ 2 rows in setFor a
NOT NULLcolumn, take note of the following points:If the column has a default value, you do not need to specify a value for this column when you insert data. The system inserts 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 inserts 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 use the
DESCstatement to queryNOT NULL,PRIMARY KEY, andUNIQUEconstraints. You can query theALL_CONSTRAINTS,DBA_CONSTRAINTS, orUSER_CONSTRAINTSview forFOREIGN KEYandCHECKconstraints.
Insert a single row of data
You can use the INSERT INTO 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 the Insert multiple rows of data in batches section.
Assume that the information about the table into which data is to be inserted is as follows:
obclient [SYS]> CREATE TABLE t_insert(
id number NOT NULL PRIMARY KEY,
name varchar(10) NOT NULL,
value number,
gmt_create DATE NOT NULL DEFAULT sysdate
);
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 [SYS]> INSERT INTO t_insert(id, name, value)
VALUES (1,'CN',10001);
Query OK, 2 rows affected
obclient [SYS]> 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 [SYS]> INSERT INTO t_insert(id, name, value, gmt_create)
VALUES (3,'EN', 10003, sysdate);
Query OK, 1 row affected
Insert multiple rows of data in batches
To insert multiple records, you can also use an INSERT INTO statement that contains multiple VALUES clauses. 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 [SYS]> 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 INTO statement for batch insertion.
Example 3: Back up all data of the t_insert table to the t_insert_bak table.
obclient [SYS]> SELECT * FROM t_insert;
+----+------+-------+------------+
| ID | NAME | VALUE | GMT_CREATE |
+----+------+-------+------------+
| 1 | CN | 10001 | 31-OCT-22 |
| 2 | US | 10002 | 31-OCT-22 |
| 3 | EN | 10003 | 31-OCT-22 |
+----+------+-------+------------+
3 rows in set
obclient [SYS]> CREATE TABLE t_insert_bak(
id number NOT NULL PRIMARY KEY,
name varchar(10) NOT NULL,
value number,
gmt_create DATE NOT NULL DEFAULT sysdate
);
Query OK, 0 rows affected
obclient [SYS]> INSERT INTO t_insert_bak SELECT * FROM t_insert;
Query OK, 2 rows affected
Records: 3 Duplicates: 0 Warnings: 0
obclient [SYS]> SELECT * FROM t_insert_bak;
+----+------+-------+------------+
| ID | NAME | VALUE | GMT_CREATE |
+----+------+-------+------------+
| 1 | CN | 10001 | 31-OCT-22 |
| 2 | US | 10002 | 31-OCT-22 |
| 3 | EN | 10003 | 31-OCT-22 |
+----+------+-------+------------+
3 rows in set
Use the MERGE INTO statement to insert data
In a batch processing task, a large number of INSERT operations may need to be performed on the target table. If the to-be-inserted records in the source table do not exist in the target table, you can also use the MERGE INTO statement to insert the records of the source table into the target table. For more information, see Replace data.
Note
If you use the INSERT INTO statement to insert data into a table that has a UNIQUE constraint, the system returns an error when duplicate records are inserted. In this case, you can use the MERGE INTO statement to update records in the table to avoid conflicts with the UNIQUE constraint.
Use the INSERT INTO statement to insert data through a DBLink
The current OceanBase Database version allows you to write data to OceanBase Database in Oracle mode and to an Oracle database through a DBLink.
Here is an example of inserting a row (11,11) into the t1 table in the remote database through a DBLink:
obclient> SELECT * FROM t1@ob_dblink;
+------+------+
| C1 | C2 |
+------+------+
| 1 | 1 |
+------+------+
1 row in set
obclient> INSERT INTO t1@ob_dblink VALUES (11,11);
Query OK, 1 row affected
obclient> commit;
Query OK, 0 rows affected
obclient> SELECT * FROM t1@ob_dblink;
+------+------+
| C1 | C2 |
+------+------+
| 1 | 1 |
| 11 | 11 |
+------+------+
2 rows in set