Forum Stats

  • 3,826,296 Users
  • 2,260,620 Discussions
  • 7,896,871 Comments

Discussions

How to return ID after inserting into table?

Rob8111
Rob8111 Member Posts: 24 Green Ribbon

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?

Tagged:

Answers

  • BluShadow
    BluShadow Member, Moderator Posts: 41,978 Red Diamond

    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?

  • BluShadow
    BluShadow Member, Moderator Posts: 41,978 Red Diamond

    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.

  • Rob8111
    Rob8111 Member Posts: 24 Green Ribbon

    Hi @BluShadow, actually I want to insert a single row and return its id.

  • Alex Nuijten
    Alex Nuijten Member Posts: 242 Silver Badge

    Then use

    INSERT INTO <table> VALUES (<values>) RETURNING ID into <variable>

    Just like @BluShadow already mentioned.

  • BluShadow
    BluShadow Member, Moderator Posts: 41,978 Red Diamond

    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...

  • Rob8111
    Rob8111 Member Posts: 24 Green Ribbon

    HI @Alex Nuijten,

    INSERT INTO <table> VALUES (<values>) RETURNING ID into <variable>

    this will not work with INSERT INTO <table1> SELECT FROM <table2>.

  • BluShadow
    BluShadow Member, Moderator Posts: 41,978 Red Diamond


    Correct. As already discussed. I'm sure Alex already knows that too.

    It's the way Oracle is.

  • mathguy
    mathguy Member Posts: 10,539 Blue Diamond
    edited May 9, 2022 3:51PM

    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 to table1.

    Then select the columns from table2 into these local variables (a SELECT ... INTO ... FROM table2 WHERE ... statement), and use the variables in an INSERT 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
    
    Rob8111