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

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 work, revamping algorithms, ensuring correctness, you know the score. Then my eyes snagge

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,

Quick Guide to User-Defined Types in Oracle PL/SQL

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