Discussions
Categories
- 196.8K All Categories
- 2.2K Data
- 239 Big Data Appliance
- 1.9K Data Science
- 450.3K Databases
- 221.7K General Database Discussions
- 3.8K Java and JavaScript in the Database
- 31 Multilingual Engine
- 550 MySQL Community Space
- 478 NoSQL Database
- 7.9K Oracle Database Express Edition (XE)
- 3K ORDS, SODA & JSON in the Database
- 544 SQLcl
- 4K SQL Developer Data Modeler
- 187K SQL & PL/SQL
- 21.3K SQL Developer
- 295.9K Development
- 17 Developer Projects
- 138 Programming Languages
- 292.5K Development Tools
- 107 DevOps
- 3.1K QA/Testing
- 646K Java
- 28 Java Learning Subscription
- 37K Database Connectivity
- 155 Java Community Process
- 105 Java 25
- 22.1K Java APIs
- 138.1K Java Development Tools
- 165.3K Java EE (Java Enterprise Edition)
- 18 Java Essentials
- 160 Java 8 Questions
- 86K Java Programming
- 80 Java Puzzle Ball
- 65.1K New To Java
- 1.7K Training / Learning / Certification
- 13.8K Java HotSpot Virtual Machine
- 94.3K Java SE
- 13.8K Java Security
- 204 Java User Groups
- 24 JavaScript - Nashorn
- Programs
- 439 LiveLabs
- 38 Workshops
- 10.2K Software
- 6.7K Berkeley DB Family
- 3.5K JHeadstart
- 5.7K Other Languages
- 2.3K Chinese
- 171 Deutsche Oracle Community
- 1.1K Español
- 1.9K Japanese
- 232 Portuguese
How to return ID after inserting into table?

Hi, I'm inserting some data into table1 from table2 using the query below inside plsql.
insert into table1 (
col1
, col2
, clo3
)
select
col1
, col2
, col3
from table2;
I want to return the ID of newly inserted row from table1.
I tried,
'RETURNING ID INTO VARIBLAE'. But this is not working in 'insert into select' query.
Is there any other way?
Answers
-
Unfortunately the RETURNING clause doesn't work directly with an INSERT ... SELECT ..., but instead works with an INSERT ... VALUES ... (also consider that your SELECT statement may query more than 1 row, so selecting a single ID to a variable isn't usually going to work anyway)
There's a workaround where you can collect the values to be inserted from the select into a collection type and then use a FORALL PL/SQL statement with an INSERT ... VALUES ... RETURNING BULK COLLECT INTO <collection type> which then gives you a collection with all the 'ID' values you want to capture.
So what exactly are you trying to achieve? Inserting a single row of data and capture the ID? or Insert multiple rows and capture all the ID's?
-
e.g.
SQL> create table t(id number, text varchar2(20)) 2 / Table created. SQL> create sequence tSeq 2 / Sequence created. SQL> create trigger tT before insert on t for each row 2 begin 3 :new.id := tSeq.nextval; 4 end; 5 / Trigger created. SQL> create type tIds as table of number; 2 / Type created. SQL> create type tNames as table of varchar2(20) 2 / Type created. SQL> declare 2 ids tIds; 3 names tNames; 4 begin 5 select ename 6 bulk collect into names 7 from emp; 8 -- 9 forall n in 1 .. names.count 10 insert into t(text) 11 values (names(n)) 12 returning id bulk collect into ids; 13 -- 14 for i in 1 .. ids.count 15 loop 16 dbms_output.put_line('Inserted '|| to_char(ids(i))); 17 end loop; 18 end; 19 / Inserted 1 Inserted 2 Inserted 3 Inserted 4 Inserted 5 Inserted 6 Inserted 7 Inserted 8 Inserted 9 Inserted 10 Inserted 11 Inserted 12 Inserted 13 Inserted 14 PL/SQL procedure successfully completed.
Obviously this uses more PGA memory as you're collecting things in memory rather than doing stuff directly with SQL.
-
Hi @BluShadow, actually I want to insert a single row and return its id.
-
Then use
INSERT INTO <table> VALUES (<values>) RETURNING ID into <variable>
Just like @BluShadow already mentioned.
-
Ok, so the key thing is...
Inserting single values and getting the ID is easily done with INSERT ... VALUES ... RETURNING n into var
Inserting from a SELECT and getting the ID or multiple ID's requires the workaround.
Oracle just doesn't support the RETURNING clause for INSERT ... SELECT ...
If you were just inserting a single column you could workaround like...
declare id number; begin insert into t(text) values ((select ename from emp where empno = 7788)) returning id into id; dbms_output.put_line('Inserted ' || to_char(id)); end; /
... but if you're inserting multiple columns then it becomes more messy doing it that way...
SQL> create table t(id number, ename varchar2(20), deptno number) 2 / Table created. SQL> create sequence tSeq 2 / Sequence created. SQL> create trigger tT before insert on t for each row 2 begin 3 :new.id := tSeq.nextval; 4 end; 5 / Trigger created. SQL> declare 2 id number; 3 begin 4 insert into t(ename, deptno) 5 values ((select ename from emp where empno = 7788), (select deptno from emp where empno = 7788)) 6 returning id into id; 7 dbms_output.put_line('Inserted ' || to_char(id)); 8 end; 9 / Inserted 1 PL/SQL procedure successfully completed.
I'm sure there must be some other funky workaround to achieve it...
-
HI @Alex Nuijten,
INSERT INTO <table> VALUES (<values>) RETURNING ID into <variable>
this will not work with INSERT INTO <table1> SELECT FROM <table2>.
-
Correct. As already discussed. I'm sure Alex already knows that too.
It's the way Oracle is.
-
Instead of using multiple scalar subqueries (and scanning the source data multiple times), and also instead of creating a record type, it seems more natural to create local scalar variables for the columns you are copying from
table2
totable1
.Then select the columns from
table2
into these local variables (aSELECT ... INTO ... FROM table2 WHERE ...
statement), and use the variables in anINSERT INTO table1 (...) VALUES ( ... )
statement. Something like this:create table t(id number generated always as identity, ename varchar2(20), deptno number) / Table T created. declare l_ename t.ename%type; l_deptno t.deptno%type; l_id number; begin select ename, deptno into l_ename, l_deptno from scott.emp where empno = 7788; insert into t (ename, deptno) values (l_ename, l_deptno) returning id into l_id; dbms_output.put_line ('Newly generated id: ' || l_id); end; / Newly generated id: 1 PL/SQL procedure successfully completed. select * from t; ID ENAME DEPTNO ----- -------------------- ---------- 1 SCOTT 20