A Twitter follower recently asked for more information on user-defined types in the PL/SQL language, and I figured the best way to answer is to offer up this blog post. PL/SQL is a strongly-typed language . Before you can work with a variable or constant, it must be declared with a type (yes, PL/SQL also supports lots of implicit conversions from one type to another, but still, everything must be declared with a type). PL/SQL offers a wide array of pre-defined data types , both in the language natively (such as VARCHAR2, PLS_INTEGER, BOOLEAN, etc.) and in a variety of supplied packages (e.g., the NUMBER_TABLE collection type in the DBMS_SQL package). Data types in PL/SQL can be scalars, such as strings and numbers, or composite (consisting of one or more scalars), such as record types, collection types and object types. You can't really declare your own "user-defined" scalars, though you can define subtypes from those scalars, which can be very helpful from the p
Well, out of my head without consulting any manual (but testing in sqlplus first) here they are:
ReplyDeleteCLEAR SCREEN
SET SERVEROUTPUT ON
CREATE OR REPLACE TYPE plch_integer_ntt IS TABLE OF INTEGER;
/
-- implicit cursor bulk collect into collection
DECLARE
l_coll plch_integer_ntt := plch_integer_ntt ();
BEGIN
SELECT LEVEL
BULK COLLECT INTO l_coll
FROM DUAL
CONNECT BY LEVEL <= 10;
FOR f_idx IN 1 .. l_coll.COUNT
LOOP
DBMS_OUTPUT.put_line (f_idx || '-' || l_coll (f_idx));
END LOOP;
END;
/
-- explicit cursor bulk collect into collection
DECLARE
l_coll plch_integer_ntt := plch_integer_ntt ();
CURSOR ten_values_cur
IS
SELECT LEVEL val
FROM DUAL
CONNECT BY LEVEL <= 10;
BEGIN
OPEN ten_values_cur;
FETCH ten_values_cur
BULK COLLECT INTO l_coll;
CLOSE ten_values_cur;
FOR f_idx IN 1 .. l_coll.COUNT
LOOP
DBMS_OUTPUT.put_line (f_idx || '-' || l_coll (f_idx));
END LOOP;
END;
/
-- explicit cursor bulk collect into collection with limits
DECLARE
l_coll plch_integer_ntt := plch_integer_ntt ();
CURSOR ten_values_cur
IS
SELECT LEVEL val
FROM DUAL
CONNECT BY LEVEL <= 1000;
BEGIN
OPEN ten_values_cur;
LOOP
FETCH ten_values_cur
BULK COLLECT INTO l_coll
LIMIT 100;
EXIT WHEN l_coll.COUNT = 0;
FOR f_idx IN 1 .. 10
LOOP
DBMS_OUTPUT.put_line (f_idx || '-' || l_coll (f_idx));
END LOOP;
exit ; -- exit now for sample purposes
END LOOP;
CLOSE ten_values_cur;
END;
/
An excellent beginning! Next?
ReplyDeleteJoao's first example could also be rewritten with:
ReplyDeleteEXECUTE IMMEDIATE 'select level from dual connect by level<=10'
BULK COLLECT INTO l_coll;
Excellent, Julius. That's another one!
ReplyDeleteAlos DML returning bulk collect into, like this
ReplyDeleteDECLARE
TYPE number$table IS TABLE OF NUMBER;
t_ids number$table;
BEGIN
DELETE FROM emp WHERE salary > 100 RETURNIG id BULK COLLECT INTO t_ids;
END;
There you go, Ilya - that was the one I thought would be hardest to recall or be aware of. When you use RETURNING for a DML statement that modifies more than one row, you will need to BULK COLLECT the values returned.
ReplyDeleteHi Steven.
DeleteYou wrote: "When you use RETURNING for a DML statement that modifies more than one row, you will need to BULK COLLECT the values returned".
Another option is to use an aggregate function, like:
UPDATE T SET... RETURNING SUM(COL1) INTO VAR1;
Thanks,
Oren.
Thanks for pointing that out, Oren.
DeleteHello Steven,
ReplyDeleteWhen I started to write my post, there were still no comments on this thread ...
now, before I post it, there are already 6 of them, you can really be proud :):)
So, I will post my comment **before** reading the other ones :)
In a first quick attempt to cover all the cases, the list seems to be as follows:
SELECT ... BULK COLLECT INTO ...
FETCH ... BULK COLLECT INTO ...
UPDATE ...
RETURNING ... BULK COLLECT INTO ...
DELETE ...
RETURNING ... BULK COLLECT INTO ...
FORALL ...
UPDATE ...
RETURNING ... BULK COLLECT INTO ...
FORALL ...
DELETE ...
RETURNING ... BULK COLLECT INTO ...
FORALL ...
INSERT ... VALUES ...
RETURNING ... BULK COLLECT INTO ...
as well as their dynamic counter-parts, like
EXECUTE IMMEDIATE
'SELECT ... '
BULK COLLECT INTO ...
EXECUTE IMMEDIATE
'UPDATE ... RETURNING ... INTO ...'
RETURNING BULK COLLECT INTO ...
EXECUTE IMMEDIATE
'DELETE ... RETURNING ... INTO ...'
RETURNING BULK COLLECT INTO ...
and so on.
I would just add that, since INSERT SELECT ... RETURNING ... is not supported,
we should use a properly designed FORALL with a single row insert, like:
FORALL ...
INSERT ... VALUES ...
RETURNING ... BULK COLLECT INTO ...
as a work-around.
All the FORALL cases can also use a dynamic statement, like in
FORALL ...
EXECUTE IMMEDIATE
'UPDATE ... RETURNING ... INTO ...'
USING ...
RETURNING BULK COLLECT INTO ...
I hope that I covered all the possible cases but, if not, I am very curious what is it that I forgot.
Thanks a lot & Best Regards,
Iudith
Very nice compilation, Iudith.
ReplyDeleteHi Steven
ReplyDeleteNice explanation, but I have a question regarding 1 piece of code.
You mentioned the following code in your 2nd program:
-- explicit cursor bulk collect into collection
DECLARE
l_coll plch_integer_ntt := plch_integer_ntt ();
but I think calling a constructor is not necessary,if you are using bulk collect.
we can change this something like below:
l_coll plch_integer_ntt ;--:= plch_integer_ntt ();
Please correct me if you find me wrong. Thanks
Regards
Shu
You are correct, Shu. When populating a collection with BULK COLLECT it is not necessary to initialize or extend first.
ReplyDeleteKool but any practical use of using bulk collect with returning clause?
ReplyDeleteI confess that I have not used it in any of my production code (PL/SQL Challenge), but I could see it being handy if I needed to produce a report or log in some way the rows modified and what to.
ReplyDeleteAnyone else out there with a use case?