Skip to main content

Accessing index of associative array in SELECT-FROM TABLE() operation

As of Oracle Database 12c Release 1, you can now use the TABLE operator with associative arrays whose types are declared in a package specification. Prior to 12.1, this was only possible with schema-level nested table and varray types. Here's a quick example:

CREATE OR REPLACE PACKAGE aa_pkg AUTHID DEFINER
IS
   TYPE record_t IS RECORD (nm VARCHAR2 (100), sal NUMBER);

   TYPE array_t IS TABLE OF record_t INDEX BY PLS_INTEGER;

   FUNCTION my_array RETURN array_t;
END;
/

 CREATE OR REPLACE PACKAGE BODY aa_pkg
IS
   FUNCTION my_array RETURN array_t
   IS
      l_return   array_t;
   BEGIN
      l_return (1).nm := 'Me'; l_return (1).sal := 1000;
      l_return (200).nm := 'You'; l_return (200).sal := 2;
      RETURN l_return;
   END;
END;
/

 DECLARE
   l_array   aa_pkg.array_t;
BEGIN
   l_array := aa_pkg.my_array;

   FOR rec IN (  SELECT * FROM TABLE (l_array) ORDER BY nm)
   LOOP
      DBMS_OUTPUT.put_line (rec.nm);
   END LOOP;
END;
/

And with nested tables and varrays, the index values used in those collections are usually not very interesting. Varrays are always densely-filled (no gaps between first and last index values). Nested tables are (or should be treated as) multisets - the order of its elements is not significant.

But with associative arrays, index values can be negative. They can be strings. And it is not terribly uncommon for associative arrays to be sparse (not every index value defined between first and last).

What if you need to access those index values in the dataset returned by the TABLE operator? In this case, I am sorry to have to tell you, you have to do some extra work. That information simply isn't available natively - which, I think, is quite reasonable. When you use SELECT-FROM TABLE you are saying, in effect, I want to treat the data as a virtual tables. Tables don't have indexes built into them. You have to specify them "on top" of the table.

In any case, the solution isn't terribly difficult. You simply add a field to your record (or attribute to object type). Or if your collection is currently a collection of scalars (list of dates or strings or numbers), then you will have to create a record or object type to hold that scalar value, plus the index value. Then that index value is available as "just another column" in your query.

Here are the steps:

1. Recompile the package specification, after adding an index field. The package body remains the same as above, so I won't repeat it below.

CREATE OR REPLACE PACKAGE aa_pkg AUTHID DEFINER 
IS 
   TYPE record_t IS RECORD 
   ( 
      idx   INTEGER, 
      nm    VARCHAR2 (100), 
      sal   NUMBER 
   ); 
 
   TYPE array_t IS TABLE OF record_t INDEX BY PLS_INTEGER; 
 
   FUNCTION my_array  RETURN array_t; 
END; 

2. Reference that index value as a column in your query:

DECLARE 
   l_array   aa_pkg.array_t; 
   l_index   PLS_INTEGER; 
BEGIN 
   l_array := aa_pkg.my_array; 
 
   l_index := l_array.FIRST; 
 
   WHILE l_index IS NOT NULL 
   LOOP 
      l_array (l_index).idx := l_index; 
      l_index := l_array.next (l_index); 
   END LOOP; 
 
   FOR rec IN (  SELECT * FROM TABLE (l_array) ORDER BY idx) 
   LOOP 
      DBMS_OUTPUT.put_line (rec.idx || ' = ' || rec.nm); 
   END LOOP; 
END; 


This script can be executed in its entirety on LiveSQL.

Comments

Popular posts from this blog

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

Why DBMS_OUTPUT.PUT_LINE should not be in your application code

A database developer recently came across my  Bulletproof PL/SQL  presentation, which includes this slide. That first item in the list caught his attention: Never put calls to DBMS_OUTPUT.PUT_LINE in your application code. So he sent me an email asking why I would say that. Well, I suppose that is the problem with publishing slide decks. All the explanatory verbiage is missing. I suppose maybe I should do a video. :-) But in the meantime, allow me to explain. First, what does DBMS_OUTPUT.PUT_LINE do? It writes text out to a buffer, and when your current PL/SQL block terminates, the buffer is displayed on your screen. [Note: there can be more to it than that. For example, you could in your own code call DBMS_OUTPUT.GET_LINE(S) to get the contents of the buffer and do something with it, but I will keep things simple right now.] Second, if I am telling you not to use this built-in, how could text from your program be displayed on your screen? Not without a lot o...

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