Write code for a living?
Feeling kind of lazy?
Then maybe you should find a way to generate some code. That's the focus of this blog post.
The bulk processing feature of PL/SQL was introduced a long, long time ago. It lets us, among other things, do this:
Lovely, concise syntax. One downside, however, is that the target collection in the BULK COLLECT INTO clause must be indexed by integer (which means all nested tables and varrays, but only INDEX BY - associative array - collections that are index by PLS_INTEGER or variations therein).
This means that if you do want to use a string-indexed collection, you need to first "dump" it into an integer-indexed array, and then move it over to a string-indexed array.
I've done this, and my code usually looks like this:
I have two solutions to that problem:
1. You can get this done with less code.
2. You can use my procedure to generate the code.
First, getting it done with less code: why populate an integer-indexed collection? Why not just use a cursor FOR loop instead? Here's the alternative, a good bit shorter.
So I wrote a couple of procedures you can use to generate either of the patterns above. You can get all the code on LiveSQL. As you will quickly see, I wrote the above code first, then turned it into a template string with tags, like "#COLUMN#". I replace the tags with the values you provide, then spit it out with DBMS_OUTPUT. Simple enough.
Here's an example of calling the procedure to generate the text, in this case showing how to use an expression to construct the string index values.
Feeling kind of lazy?
Then maybe you should find a way to generate some code. That's the focus of this blog post.
The bulk processing feature of PL/SQL was introduced a long, long time ago. It lets us, among other things, do this:
Lovely, concise syntax. One downside, however, is that the target collection in the BULK COLLECT INTO clause must be indexed by integer (which means all nested tables and varrays, but only INDEX BY - associative array - collections that are index by PLS_INTEGER or variations therein).
This means that if you do want to use a string-indexed collection, you need to first "dump" it into an integer-indexed array, and then move it over to a string-indexed array.
I've done this, and my code usually looks like this:
DECLARE
CURSOR c IS select last_name, first_name, employee_id
from employees where department_id = 30;
TYPE t IS TABLE OF c%ROWTYPE;
c_limit CONSTANT PLS_INTEGER := 100;
l_rows_by_integer t;
TYPE vct IS TABLE OF c%ROWTYPE INDEX BY VARCHAR2(32767);
l_rows_by_varchar2 vct;
l_index VARCHAR2(32767);
BEGIN
OPEN c;
LOOP
FETCH c BULK COLLECT INTO l_rows_by_integer LIMIT c_limit;
EXIT WHEN l_rows_by_integer.COUNT = 0;
FOR indx IN 1 .. l_rows_by_integer.COUNT
LOOP
l_rows_by_varchar2 (l_rows_by_integer (indx).last_name)
:= l_rows_by_integer (indx);
END LOOP;
END LOOP;
CLOSE c;
/* Iterate through the string-indexed collection */
l_index := l_rows_by_varchar2.FIRST;
WHILE l_index IS NOT NULL
LOOP
DBMS_OUTPUT.PUT_LINE (l_rows_by_varchar2(l_index).last_name);
l_index := l_rows_by_varchar2.NEXT (l_index);
END LOOP;
END;
Well, dang, that's a lot of code to have to write!I have two solutions to that problem:
1. You can get this done with less code.
2. You can use my procedure to generate the code.
First, getting it done with less code: why populate an integer-indexed collection? Why not just use a cursor FOR loop instead? Here's the alternative, a good bit shorter.
DECLARE
CURSOR c IS select last_name, first_name, employee_id
from employees where department_id = 30;
TYPE vct IS TABLE OF c%ROWTYPE INDEX BY VARCHAR2(32767);
l_rows_by_varchar2 vct;
l_index VARCHAR2(32767);
BEGIN
FOR rec IN (select last_name, first_name, employee_id
from employees where department_id = 30)
LOOP
l_rows_by_varchar2 (rec.last_name) := rec;
END LOOP;
CLOSE c;
/* Iterate through the string-indexed collection */
l_index := l_rows_by_varchar2.FIRST;
WHILE l_index IS NOT NULL
LOOP
DBMS_OUTPUT.PUT_LINE (l_rows_by_varchar2(l_index).last_name);
l_index := l_rows_by_varchar2.NEXT (l_index);
END LOOP;
END;
Still, why write that code at all? I was inspired by Connor McDonald's recent blog post and fantastic new auditing utility that generates a lot of code.So I wrote a couple of procedures you can use to generate either of the patterns above. You can get all the code on LiveSQL. As you will quickly see, I wrote the above code first, then turned it into a template string with tags, like "#COLUMN#". I replace the tags with the values you provide, then spit it out with DBMS_OUTPUT. Simple enough.
Here's an example of calling the procedure to generate the text, in this case showing how to use an expression to construct the string index values.
BEGIN
gen_select_into_index_by2 (
'select last_name, first_name, last_name||''-''||first_name combined_name, employee_id
from employees where department_id = 30', 'employees', 'combined_name');
END;
Hope you find it useful!
You know Steven my thoughts, after learning Python in past months and how easy and elegant coding using the iter , comprehension concepts.. would love to see this type of features available in PL/SQL.. but given the legacy and strict pascal like nature of pl/sql sql one could think better support a py/sql new bnf instead? Or -I wonder- boost extra operators constructs. As senior oracle developer this python recent addition to my languages skillset really got me hyped.
ReplyDeleteAlso if we want continue capturing new generations we (Oracle) really need to target developers hearts.
Thanks for sharing your thoughts, emanueol.
DeleteThe next release of Oracle Database and PL/SQL will greatly expand iterator features. See https://asktom.oracle.com/pls/apex/f?p=100:551::::RP,551:P551_CLASS_ID:8665 for more details.
As for "strict pascal like nature", actually it is "somewhat strict ada like nature". :-)
Finally, while I can't speak for the PL/SQL dev team and certainly can't predict the future for PL/SQL, here's my sense of things:
a. Over time, you will likely see the ability to write your language of choice inside the database, as you can now with PL/SQL and Java (just two choices!). See: https://oracle.github.io/oracle-db-mle/
b. PL/SQL is what it is. It's kind of late to jam it full of language constructs and syntax from other paradigms. It will continue to improve over time, and certainly we should make it easier and more elegant for people to write PL/SQL program units. But you won't see a wholesale introduction of Python syntax and JavaScript syntax and so on.