Home » SQL & PL/SQL » SQL & PL/SQL » RETURNING BULK COLLECT INTO COLLECTION (12C )
RETURNING BULK COLLECT INTO COLLECTION [message #673561] Fri, 23 November 2018 22:45 Go to next message
shawaj
Messages: 89
Registered: January 2016
Member
Hi experts,
I am using returning bulk collect in dynamic sql but getting error.
Please help.

CREATE TABLE employees (
  empno   		NUMBER(4) CONSTRAINT employees_pk PRIMARY KEY,
  ename 		VARCHAR2(10),
  job           VARCHAR2(9),
  manager_id    NUMBER(4),
  hiredate      DATE,
  salary        NUMBER(7,2),
  commission    NUMBER(7,2),
  deptno		NUMBER(2)
);

INSERT INTO employees VALUES (7369,'SMITH','CLERK',7902,to_date('17-12-1980','dd-mm-yyyy'),800,NULL,20);
INSERT INTO employees VALUES (7499,'ALLEN','SALESMAN',7698,to_date('20-2-1981','dd-mm-yyyy'),1600,300,30);
INSERT INTO employees VALUES (7521,'WARD','SALESMAN',7698,to_date('22-2-1981','dd-mm-yyyy'),1250,500,30);
INSERT INTO employees VALUES (7566,'JONES','MANAGER',7839,to_date('2-4-1981','dd-mm-yyyy'),2975,NULL,20);
INSERT INTO employees VALUES (7654,'MARTIN','SALESMAN',7698,to_date('28-9-1981','dd-mm-yyyy'),1250,1400,30);
INSERT INTO employees VALUES (7698,'BLAKE','MANAGER',7839,to_date('1-5-1981','dd-mm-yyyy'),2850,NULL,30);
INSERT INTO employees VALUES (7782,'CLARK','MANAGER',7839,to_date('9-6-1981','dd-mm-yyyy'),2450,NULL,10);
INSERT INTO employees VALUES (7788,'SCOTT','ANALYST',7566,to_date('13-JUL-87','dd-mm-rr')-85,3000,NULL,20);
INSERT INTO employees VALUES (7839,'KING','PRESIDENT',NULL,to_date('17-11-1981','dd-mm-yyyy'),5000,NULL,10);
INSERT INTO employees VALUES (7844,'TURNER','SALESMAN',7698,to_date('8-9-1981','dd-mm-yyyy'),1500,0,30);
INSERT INTO employees VALUES (7876,'ADAMS','CLERK',7788,to_date('13-JUL-87', 'dd-mm-rr')-51,1100,NULL,20);
INSERT INTO employees VALUES (7900,'JAMES','CLERK',7698,to_date('3-12-1981','dd-mm-yyyy'),950,NULL,30);
INSERT INTO employees VALUES (7902,'FORD','ANALYST',7566,to_date('3-12-1981','dd-mm-yyyy'),3000,NULL,20);
INSERT INTO employees VALUES (7934,'MILLER','CLERK',7782,to_date('23-1-1982','dd-mm-yyyy'),1300,NULL,10);
COMMIT;

CREATE TABLE T1 AS SELECT * FROM EMPLOYEES WHERE 1=2;


DECLARE
	CURSOR C1 IS 
	SELECT  empno,ename,salary FROM employees WHERE 1=2;
	TYPE NameList IS TABLE OF C1%ROWTYPE;
	enames    NameList;
	sql_stmt  VARCHAR(200);
	
BEGIN
   sql_stmt := 'UPDATE employees SET SAL= SAL+10 RETURNING empno,ename,salary INTO :1,:2,:3';
   EXECUTE IMMEDIATE sql_stmt
      RETURNING BULK COLLECT INTO enames,enames,enames;
	  
	  FORALL i IN enames.first..enames.last
	  INSERT INTO t1(empno,ename,salary) values(enames(i).empno,enames(i).ename,enames(i).salary);
	  commit;
END;
/
RETURNING BULK COLLECT INTO enames,enames;
                                  *
ERROR at line 12:
ORA-06550: line 12, column 35:
PLS-00597: expression 'ENAMES' in the INTO list is of wrong type
ORA-06550: line 11, column 4:
PL/SQL: Statement ignored

Re: RETURNING BULK COLLECT INTO COLLECTION [message #673562 is a reply to message #673561] Sat, 24 November 2018 01:05 Go to previous messageGo to next message
Michel Cadot
Messages: 68625
Registered: March 2007
Location: Nanterre, France, http://...
Senior Member
Account Moderator

Many errors, let us fix one by one:

RETURNING empno...
INTO enames...
enames NameList;
TYPE NameList IS TABLE OF C1%ROWTYPE;
CURSOR C1 IS SELECT empno,ename,salary FROM...

Do you think that empno is of C1%ROWTYPE type?

[Updated on: Sat, 24 November 2018 01:06]

Report message to a moderator

Re: RETURNING BULK COLLECT INTO COLLECTION [message #673563 is a reply to message #673562] Sat, 24 November 2018 02:35 Go to previous messageGo to next message
shawaj
Messages: 89
Registered: January 2016
Member
DECLARE
  --TYPE NameList IS TABLE OF VARCHAR2(15);
  TYPE NameList IS TABLE OF employees.ename%type;
  --cursor c1 is select ename from employees where 1=2;
  TYPE NameList IS TABLE OF c1%rowtype;
   enames    NameList;
   sql_stmt  VARCHAR(200);
   
   
   
BEGIN
   sql_stmt := 'UPDATE employees SET salary=salary+10 RETURNING ename INTO :2';
   EXECUTE IMMEDIATE sql_stmt  
      RETURNING BULK COLLECT INTO enames;
	  
	  forall i in enames.first..enames.last
	  insert into t1(ename) values(enames(i));
END; 
/

The above code is working fine but i want to store multiple ( 8 ) columns in "T1" table so how i can do it???

[Updated on: Sat, 24 November 2018 02:36]

Report message to a moderator

Re: RETURNING BULK COLLECT INTO COLLECTION [message #673564 is a reply to message #673563] Sat, 24 November 2018 02:54 Go to previous messageGo to next message
Michel Cadot
Messages: 68625
Registered: March 2007
Location: Nanterre, France, http://...
Senior Member
Account Moderator

You can use several arrays:
SQL> DECLARE
  2    TYPE NameList IS TABLE OF employees.last_name%TYPE;
  3    names   NameList;
  4    TYPE SalList IS TABLE OF employees.salary%TYPE;
  5    sals    SalList;
  6    dept_id NUMBER := 30;
  7  BEGIN
  8    UPDATE employees SET salary = salary * 1.1
  9    WHERE department_id = 30
 10    RETURNING last_name, salary
 11    BULK COLLECT INTO names, sals;
 12
 13    DBMS_OUTPUT.PUT_LINE ('Updated ' || SQL%ROWCOUNT || ' rows:');
 14    FOR i IN names.FIRST .. names.LAST
 15    LOOP
 16      DBMS_OUTPUT.PUT_LINE ('Employee ' || names(i) || ': ' || sals(i));
 17    END LOOP;
 18    ROLLBACK;
 19  END;
 20  /
Updated 6 rows:
Employee Raphaely: 12100
Employee Khoo: 3410
Employee Baida: 3190
Employee Tobias: 3080
Employee Himuro: 2860
Employee Colmenares: 2750

PL/SQL procedure successfully completed.
Or you can use a record:
SQL> DECLARE
  2    TYPE EmpRec IS RECORD (last_name  employees.last_name%TYPE,
  3                           salary     employees.salary%TYPE);
  4    emp_info EmpRec;
  5    emp_id   NUMBER := 100;
  6  BEGIN
  7    UPDATE employees SET salary = salary * 1.1
  8      WHERE employee_id = emp_id
  9      RETURNING last_name, salary INTO emp_info;
 10    DBMS_OUTPUT.PUT_LINE
 11      ('Just gave a raise to ' || emp_info.last_name ||
 12       ', who now makes ' || emp_info.salary);
 13    ROLLBACK;
 14  END;
 15  /
Just gave a raise to King, who now makes 26400

PL/SQL procedure successfully completed.
As exercise, I let you mix both examples.
Please post the solution you'll find for future readers (or the error you'll get, we can learn from errors).

Re: RETURNING BULK COLLECT INTO COLLECTION [message #673565 is a reply to message #673564] Sat, 24 November 2018 03:29 Go to previous messageGo to next message
shawaj
Messages: 89
Registered: January 2016
Member
i have to use this code in dynamic sql not native Please give idea how we can use this in dynamic sql.

  1  DECLARE
  2     TYPE EmpRec IS RECORD (last_name  employees.ename%TYPE,
  3                            salary     employees.salary%TYPE);
  4     emp_info EmpRec;
  5     emp_id   NUMBER := 100;
  6     sql_stmt varchar2(500);
  7   BEGIN
  8     sql_stmt :='UPDATE employees SET salary = salary * 1.1 RETURNING ename,salary INTO :1,:2';
  9     EXECUTE IMMEDIATE sql_stmt
 10       RETURNING BULK COLLECT into emp_info;
 11     DBMS_OUTPUT.PUT_LINE
 12       ('Just gave a raise to ' || emp_info.last_name ||
 13        ', who now makes ' || emp_info.salary);
 14     ROLLBACK;
 15*  END;
SQL> /
     RETURNING BULK COLLECT into emp_info;
                                 *
ERROR at line 10:
ORA-06550: line 10, column 34:
PLS-00497: cannot mix between single row and multi-row (BULK) in INTO list

Michel Cadot wrote on Sat, 24 November 2018 02:54

You can use several arrays:
SQL> DECLARE
  2    TYPE NameList IS TABLE OF employees.last_name%TYPE;
  3    names   NameList;
  4    TYPE SalList IS TABLE OF employees.salary%TYPE;
  5    sals    SalList;
  6    dept_id NUMBER := 30;
  7  BEGIN
  8    UPDATE employees SET salary = salary * 1.1
  9    WHERE department_id = 30
 10    RETURNING last_name, salary
 11    BULK COLLECT INTO names, sals;
 12
 13    DBMS_OUTPUT.PUT_LINE ('Updated ' || SQL%ROWCOUNT || ' rows:');
 14    FOR i IN names.FIRST .. names.LAST
 15    LOOP
 16      DBMS_OUTPUT.PUT_LINE ('Employee ' || names(i) || ': ' || sals(i));
 17    END LOOP;
 18    ROLLBACK;
 19  END;
 20  /
Updated 6 rows:
Employee Raphaely: 12100
Employee Khoo: 3410
Employee Baida: 3190
Employee Tobias: 3080
Employee Himuro: 2860
Employee Colmenares: 2750

PL/SQL procedure successfully completed.
Or you can use a record:
SQL> DECLARE
  2    TYPE EmpRec IS RECORD (last_name  employees.last_name%TYPE,
  3                           salary     employees.salary%TYPE);
  4    emp_info EmpRec;
  5    emp_id   NUMBER := 100;
  6  BEGIN
  7    UPDATE employees SET salary = salary * 1.1
  8      WHERE employee_id = emp_id
  9      RETURNING last_name, salary INTO emp_info;
 10    DBMS_OUTPUT.PUT_LINE
 11      ('Just gave a raise to ' || emp_info.last_name ||
 12       ', who now makes ' || emp_info.salary);
 13    ROLLBACK;
 14  END;
 15  /
Just gave a raise to King, who now makes 26400

PL/SQL procedure successfully completed.
As exercise, I let you mix both examples.
Please post the solution you'll find for future readers (or the error you'll get, we can learn from errors).

[Updated on: Sat, 24 November 2018 20:39]

Report message to a moderator

Re: RETURNING BULK COLLECT INTO COLLECTION [message #673578 is a reply to message #673565] Sun, 25 November 2018 01:41 Go to previous messageGo to next message
shawaj
Messages: 89
Registered: January 2016
Member
I find the following way to fulfill my need. If you have something better then reply.
Thanks Michel Cadot.
DECLARE
   TYPE NameList IS TABLE OF employees.ename%type;
   TYPE SalList is TABLE OF employees.salary%type;
   sql_stmt varchar2(500);
   l_name  NameList;
   l_sal   SalList;
 BEGIN
   sql_stmt :='UPDATE employees SET salary = salary * 1.1 RETURNING ename,salary INTO :1,:2';
   EXECUTE IMMEDIATE sql_stmt
     RETURNING bulk collect into l_name,l_sal;
   delete t1;
   forall i in 1..l_name.last
   insert into t1(ename,salary) values(l_name(i),l_sal(i));
 END;
/
Re: RETURNING BULK COLLECT INTO COLLECTION [message #673728 is a reply to message #673578] Thu, 06 December 2018 14:40 Go to previous messageGo to next message
Bill B
Messages: 1971
Registered: December 2004
Senior Member
I see nothing in your code that would require you to use execute immediate. What is your justification for using such inefficient code?
Re: RETURNING BULK COLLECT INTO COLLECTION [message #673729 is a reply to message #673578] Thu, 06 December 2018 15:19 Go to previous messageGo to next message
BlackSwan
Messages: 26766
Registered: January 2009
Location: SoCal
Senior Member
shawaj wrote on Sat, 24 November 2018 23:41
I find the following way to fulfill my need. If you have something better then reply.
Thanks Michel Cadot.
DECLARE
   TYPE NameList IS TABLE OF employees.ename%type;
   TYPE SalList is TABLE OF employees.salary%type;
   sql_stmt varchar2(500);
   l_name  NameList;
   l_sal   SalList;
 BEGIN
   sql_stmt :='UPDATE employees SET salary = salary * 1.1 RETURNING ename,salary INTO :1,:2';
   EXECUTE IMMEDIATE sql_stmt
     RETURNING bulk collect into l_name,l_sal;
   delete t1;
   forall i in 1..l_name.last
   insert into t1(ename,salary) values(l_name(i),l_sal(i));
 END;
/
Never do in PL/SQL that which can be done in plain SQL; since plain SQL is faster & more efficient.
Re: RETURNING BULK COLLECT INTO COLLECTION [message #674415 is a reply to message #673729] Sat, 26 January 2019 10:44 Go to previous messageGo to next message
shawaj
Messages: 89
Registered: January 2016
Member
Okay, but in my project update statement will generated at run time. I don't know complete statement at design time. So i have to use execute immediate..
Re: RETURNING BULK COLLECT INTO COLLECTION [message #674420 is a reply to message #674415] Sat, 26 January 2019 12:15 Go to previous message
BlackSwan
Messages: 26766
Registered: January 2009
Location: SoCal
Senior Member
> sql_stmt :='UPDATE employees SET salary = salary * 1.1 RETURNING ename,salary INTO :1,:2';
UPDATE above changes EVERY row in EMPLOYEES table & will fail trying to RETURN a single scalar value.
Previous Topic: SQL Query execute more records in WHERE CLAUSE
Next Topic: DataMapper - JSON -> XML - Add a colon in XML tag
Goto Forum:
  


Current Time: Thu Mar 28 19:36:48 CDT 2024