Skip to main content

Three Hot Tips for Working With Collections


Collections in PL/SQL make it easy for you to implement lists, arrays, stacks, queues, etc. They come in three flavors: associative arrays, nested tables, and varrays. The three types of collections share many features, and also have their own special characteristics.

Here are some tips for making the most of collections. At the bottom of the post, I offer links to a number of resources for diving in more deeply on collections.

You Can Query From Collections

Collections are, for the most part, variables you will declare and manipulate in PL/SQL. But you can query from them using the TABLE operator (and in 12.2 and higher you even leave off that operator).

Use this feature to:
  • Manipulate table data and in-session collection data within a single SELECT.
  • Use the set-oriented power of SQL on your in-session data.
  • Build table functions (functions that return collections and can be called in the FROM clause of a query.
Here's a simple demonstration:

CREATE OR REPLACE TYPE list_of_names_t
   IS TABLE OF VARCHAR2 (100);
/

DECLARE
   happyfamily     list_of_names_t := list_of_names_t ();
BEGIN
   happyfamily.EXTEND (7);
   happyfamily (1) := 'Veva';
   happyfamily (2) := 'Chris';
   happyfamily (3) := 'Lauren';
   happyfamily (4) := 'Loey';
   happyfamily (5) := 'Eli';
   happyfamily (6) := 'Steven';
   happyfamily (7) := 'Juna';

   FOR rec IN (  SELECT COLUMN_VALUE the_name
                   FROM TABLE (happyfamily)
               ORDER BY the_name)
   LOOP
      DBMS_OUTPUT.put_line (rec.the_name);
   END LOOP;
END;
/

Chris
Eli
Juna
Lauren
Loey
Steven
Veva

Prior to Oracle Database 12c, you could only use nested tables and varrays with the TABLE operator. But with 12.1 and above, you can also use it with integer-indexed associative arrays.

You can have a lot more than simply constructing a simple select around your collection (or a function that returns the collection). You can join that collection with other collections or other tables. You can perform set-level operations like UNION and MINUS. You can, in short, treat that collection as a read-only set of rows and columns like any other.

LiveSQL offers a number of scripts demonstrating the TABLE operator here

Collections Consume Session (PGA) Memory

Just like almost every other type of variable (or constant), collections use PGA - process global area - memory, rather than SGA - system global area - memory. This means that the memory for collections is consumed per session. 

Suppose you have a program that populates a collection with 1000s of elements of data (which could even be records, not simply scalar values). In that case, every session that executes your program will use that same amount of memory. Things could get out of hand quickly.

When writing your program, ask yourself how many sessions might run it simultaneously and if there are ways to manage/limit the amount of memory used to populate the collection.

If, for example, you are using BULK COLLECT to populate a collection from a query, stay away from SELECT-BULK COLLECT-INTO. That approach could cause issues down the line, as the volume of data returned by the query increases. Consider, instead, using an explicit cursor, with a FETCH statement and a LIMIT clause. The program might need to retrieve 1M rows, but you can fetch just 100 or 1000 at a time, and therefore cap the total PGA consumed (and reused).

You'll find lots more information about setting that limit value here.

I offer a package to help you analyze how much PGA memory your session has consumed here.


FOR Loops Don't Work with Sparse Collections

Many of your collections will be dense (all index values between lowest and highest are defined), but in some cases (especially with associative arrays), your collections will be sparse. If you try to use a numeric FOR loop to iterate through the collection's elements, you will hit a NO_DATA_FOUND exception.

Instead, use the navigation methods (FIRST, LAST, NEXT, PRIOR) to move from one defined index value to the next, and "skip over" undefined values.

In the first block below, l_animals.FIRST returns -100 and that name is then printed. But the next integer higher than -100 is -99. That is not a defined index value, so the attempt to read l_animals(-99) causes the PL/SQL runtime engine to raise a NO_DATA_FOUND exception.

In the second block, I again start with the index value returned by a call to the FIRST method. But I then use NEXT to find the next highest defined index value. So it takes me straight to 1000 and I display the name of the species at that location. The subsequent call to NEXT returns NULL and the loop stops.

Note: Lupus is the species name for wolf, and Loxodonta is the species name for African elephants. May they all live long and prosper!

DECLARE
   TYPE species_t IS TABLE OF VARCHAR2(10)
      INDEX BY PLS_INTEGER;

   l_animals   species_t;
BEGIN
   l_animals (-100) := 'Lupus';
   l_animals (1000) := 'Loxodonta';

   FOR indx IN l_animals.FIRST .. l_animals.LAST
   LOOP
      DBMS_OUTPUT.put_line (l_animals (indx));
   END LOOP;
END;
/

Lupus
ORA-01403: no data found 

DECLARE
   TYPE species_t IS TABLE OF VARCHAR2(10)
      INDEX BY PLS_INTEGER;

   l_animals   species_t;
   l_index PLS_INTEGER;
BEGIN
   l_animals (-100) := 'Lupus';
   l_animals (1000) := 'Loxodonta';

   l_index := l_animals.FIRST;
   
   WHILE l_index IS NOT NULL
   LOOP
      DBMS_OUTPUT.put_line (l_animals (l_index));
      l_index := l_animals.NEXT (l_index);
   END LOOP;
END;
/

Lupus
Loxodonta


You might think to yourself: OK, I will never use a FOR loop with collections. I will always use a WHILE loop with FIRST and NEXT (or LAST and PRIOR to go backwards). That way, it'll work whether it is sparse or dense.

That approach probably will not cause any trauma (performance will be fine), but remember that if you do this, you will never notice that a collection which was supposed to be dense actually became sparse due to a problem in your code (or user error :-) )! In other words, you may be taking out "insurance" that covers up a bug!

More on Collections

How about over 5 hours of free, video-based instruction on collections?

How about over 45 scripts on LiveSQL?

Or Tim Hall's ORACLE-BASE article on collections.

Have at it!


Comments

  1. Thank you. Very good insight into arrays.

    ReplyDelete
  2. where were you all these years. Awesome articles. I am fan of Ask Tom - Now Tim :)...

    ReplyDelete

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