Skip to main content

Generate code to move rows to string indexed collections

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:
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!

Comments

  1. 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.
    Also if we want continue capturing new generations we (Oracle) really need to target developers hearts.

    ReplyDelete
    Replies
    1. Thanks for sharing your thoughts, emanueol.

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

      Delete

Post a Comment

Popular posts from this blog

Running out of PGA memory with MULTISET ops? Watch out for DISTINCT!

A PL/SQL team inside Oracle made excellent use of nested tables and MULTISET operators in SQL, blending data in tables with procedurally-generated datasets (nested tables).  All was going well when they hit the dreaded: ORA-04030: out of process memory when trying to allocate 2032 bytes  They asked for my help.  The error occurred on this SELECT: SELECT  *    FROM header_tab trx    WHERE (generated_ntab1 SUBMULTISET OF trx.column_ntab)       AND ((trx.column_ntab MULTISET             EXCEPT DISTINCT generated_ntab2) IS EMPTY) The problem is clearly related to the use of those nested tables. Now, there was clearly sufficient PGA for the nested tables themselves. So the problem was in executing the MULTISET-related functionality. We talked for a bit about dropping the use of nested tables and instead doing everything in SQL, to avoid the PGA error. That would, however require lots of wo...

How to Pick the Limit for BULK COLLECT

This question rolled into my In Box today: In the case of using the LIMIT clause of BULK COLLECT, how do we decide what value to use for the limit? First I give the quick answer, then I provide support for that answer Quick Answer Start with 100. That's the default (and only) setting for cursor FOR loop optimizations. It offers a sweet spot of improved performance over row-by-row and not-too-much PGA memory consumption. Test to see if that's fast enough (likely will be for many cases). If not, try higher values until you reach the performance level you need - and you are not consuming too much PGA memory.  Don't hard-code the limit value: make it a parameter to your subprogram or a constant in a package specification. Don't put anything in the collection you don't need. [from Giulio Dottorini] Remember: each session that runs this code will use that amount of memory. Background When you use BULK COLLECT, you retrieve more than row with each fetch, ...

PL/SQL 101: Three ways to get error message/stack in PL/SQL

The PL/SQL Challenge quiz for 10 September - 16 September 2016 explored the different ways you can obtain the error message / stack in PL/SQL. Note: an error stack is a sequence of multiple error messages that can occur when an exception is propagated and re-raised through several layers of nested blocks. The three ways are: SQLERRM - The original, traditional and (oddly enough) not currently recommended function to get the current error message. Not recommended because the next two options avoid a problem which you are unlikely  to run into: the error stack will be truncated at 512 bytes, and you might lose some error information. DBMS_UTILITY.FORMAT_ERROR_STACK - Returns the error message / stack, and will not truncate your string like SQLERRM will. UTL_CALL_STACK API - Added in Oracle Database 12c, the UTL_CALL_STACK package offers a comprehensive API into the execution call stack, the error stack and the error backtrace.  Note: check out this LiveSQL script if...