Oracle 23ai (23.9) — Introducing Non-Positional INSERT INTO SET Clause
If you are familiar with Oracle Database, you know the basic INSERT INTO command. Let me briefly remind you of its traditional usage with some simple examples:
SQL> CREATE TABLE vahid.tbl (
id NUMBER,
name VARCHAR2(100),
last_name VARCHAR2(100)
);
Table created.
SQL> INSERT INTO vahid.tbl VALUES (1, 'VAHID', 'YOUSEFZADEH');
1 row created.
SQL> INSERT INTO vahid.tbl (name, last_name) VALUES ('VAHID', 'YOUSEFZADEH');
1 row created.When working with tables containing many columns, this standard syntax can become difficult to read and maintain, as it is not always obvious which values correspond to which columns.
New Feature in Oracle 23ai (23.9): INSERT INTO ... SET Clause
Oracle 23ai (23.9) introduces a new syntax that simplifies the INSERT INTO command by allowing a SET clause similar to that used in UPDATE statements. For example:
SQL> INSERT INTO vahid.tbl SET id = 1, name = 'VAHID', last_name = 'YOUSEFZADEH';
1 row created.As you can see, this syntax removes the need for parentheses around column-value pairs, improving readability.
Limitation: Multiple Row Inserts
However, this new syntax currently does not support inserting multiple rows without parentheses. To insert multiple rows, you must still use parentheses as follows:
SQL> INSERT INTO vahid.tbl SET
(id = 1, name = 'VAHID', last_name = 'YOUSEFZADEH'),
(id = 2, name = 'Bahman', last_name = 'Garosi');
2 rows created.The BY NAME Clause for Subquery Inserts
Another valuable addition in Oracle 23.9 is the BY NAME clause, which simplifies inserting data from a subquery. Traditionally, when inserting rows from a subquery, the order of columns in the SELECT statement must match the order of columns in the target table. This can be error-prone and cumbersome.
With the BY NAME clause, Oracle matches columns by name or alias rather than by position. This flexibility allows columns to be listed in any order.
Comments
Post a Comment