PL/SQL User's Guide and Reference 10g Release 1 (10.1) Part Number B10807-01 |
|
|
View PDF |
A collection is an ordered group of elements, all of the same type (for example, the grades for a class of students). Each element has a unique subscript that determines its position in the collection. PL/SQL offers three kinds of collections: associative arrays, nested tables, and varrays (short for variable-size arrays). Nested tables extend the functionality of associative arrays (formerly called "PL/SQL tables" or "index-by tables").
Collections work like the arrays found in most third-generation programming languages. Collections can have only one dimension. Most collections are indexed by integers, although associative arrays can also be indexed by strings. To model multi-dimensional arrays, you can declare collections whose items are other collections.
Nested tables and varrays can store instances of an object type and, conversely, can be attributes of an object type. Collections can also be passed as parameters. You can use them to move columns of data into and out of database tables or between client-side applications and stored subprograms.
For more information, see "Defining Collection Types".
Syntax
Description of the illustration element_type.gif
Keyword and Parameter Description
Any PL/SQL datatype except BINARY_INTEGER
, BOOLEAN
, LONG
, LONG
RAW
, NATURAL
, NATURALN
, PLS_INTEGER
, POSITIVE
, POSITIVEN
, REF
CURSOR
, SIGNTYPE
, or STRING
. Also, with varrays, element_type
cannot be BLOB
, CLOB
, or an object type with BLOB
or CLOB
attributes.
Optional. Defines an associative array, where you specify the subscript values to use rather than the system defining them in sequence.
type_name
can be BINARY_INTEGER
, PLS_INTEGER
, or a string type such as VARCHAR2
.
A positive integer literal that specifies the maximum size of a varray, which is the maximum number of elements the varray can contain.
A user-defined collection type that was defined using the datatype specifier TABLE
or VARRAY
.
Usage Notes
Nested tables extend the functionality of index-by tables, so they differ in several ways. See "Choosing Between Nested Tables and Associative Arrays".
Every element reference includes the collection name and one or more subscripts enclosed in parentheses; the subscripts determine which element is processed. Except for associative arrays, which can have negative subscripts, collection subscripts have a fixed lower bound of 1. Subscripts for multilevel collections are evaluated in any order; if a subscript includes an expression that modifies the value of a different subscript, the result is undefined.
You can define all three collection types in the declarative part of any PL/SQL block, subprogram, or package. But, only nested table and varray types can be CREATE
d and stored in an Oracle database.
Associative arrays and nested tables can be sparse (have non-consecutive subscripts), but varrays are always dense (have consecutive subscripts). Unlike nested tables, varrays retain their ordering and subscripts when stored in the database.
Initially, associative arrays are sparse. That enables you, for example, to store reference data in a temporary variable using a primary key (account numbers or employee numbers for example) as the index.
Collections follow the usual scoping and instantiation rules. In a package, collections are instantiated when you first reference the package and cease to exist when you end the database session. In a block or subprogram, local collections are instantiated when you enter the block or subprogram and cease to exist when you exit.
Until you initialize it, a nested table or varray is atomically null (that is, the collection itself is null, not its elements). To initialize a nested table or varray, you use a constructor, which is a system-defined function with the same name as the collection type. This function "constructs" a collection from the elements passed to it.
Because nested tables and varrays can be atomically null, they can be tested for nullity. However, they cannot be compared for equality or inequality. This restriction also applies to implicit comparisons. For example, collections cannot appear in a DISTINCT
, GROUP
BY
, or ORDER
BY
list.
Collections can store instances of an object type and, conversely, can be attributes of an object type. Collections can also be passed as parameters. You can use them to move columns of data into and out of database tables or between client-side applications and stored subprograms.
When calling a function that returns a collection, you use the following syntax to reference elements in the collection:
collection_name(parameter_list)(subscript)
With the Oracle Call Interface (OCI) or the Oracle Precompilers, you can bind host arrays to index-by tables declared as the formal parameters of a subprogram. That lets you pass host arrays to stored functions and procedures.
Examples
To specify the element type of a collection, you can use %TYPE
or %ROWTYPE
:
DECLARE TYPE JobList IS VARRAY(10) OF employees.job_id%TYPE; -- based on column TYPE EmpFile IS VARRAY(150) OF employees%ROWTYPE; -- based on database table CURSOR c1 IS SELECT * FROM departments; TYPE DeptFile IS TABLE OF c1%ROWTYPE; -- based on cursor BEGIN NULL; END; /
You can use a RECORD
type to specify the element type of a collection:
DECLARE TYPE Entry IS RECORD ( term VARCHAR2(20), meaning VARCHAR2(200)); TYPE Glossary IS VARRAY(250) OF Entry; BEGIN NULL; END; /
The following example declares an associative array of records. Each element of the table stores a row from a database table.
DECLARE TYPE EmpTabTyp IS TABLE OF employees%ROWTYPE INDEX BY BINARY_INTEGER; emp_tab EmpTabTyp; BEGIN /* Retrieve employee record. */ SELECT * INTO emp_tab(100) FROM employees WHERE employee_id = 100; END; /
When defining a VARRAY
type, you must specify its maximum size. The following example defines a type that stores up to 366 dates:
DECLARE TYPE Calendar IS VARRAY(366) OF DATE; BEGIN NULL; END; /
Once you define a collection type, you can declare collections of that type, as the following SQL*Plus script shows:
CREATE TYPE Project AS OBJECT( project_no NUMBER(2), title VARCHAR2(35), cost NUMBER(7,2)); / CREATE TYPE ProjectList AS VARRAY(50) OF Project; -- VARRAY type / CREATE TABLE temp_department ( idnum NUMBER(2), name VARCHAR2(15), budget NUMBER(11,2), projects ProjectList); DROP TABLE temp_department; DROP TYPE ProjectList; DROP TYPE Project;
The identifier projects
represents an entire varray. Each element of projects
stores a Project
object.
The following example declares a nested table as the parameter of a packaged procedure:
CREATE PACKAGE personnel AS TYPE Staff IS TABLE OF Employee; PROCEDURE award_bonuses (members IN Staff); END personnel; / DROP PACKAGE personnel;
You can specify a collection type in the RETURN
clause of a function spec:
DECLARE TYPE SalesForce IS VARRAY(20) OF employees%ROWTYPE; FUNCTION top_performers (n INTEGER) RETURN SalesForce IS BEGIN RETURN NULL; END; BEGIN NULL; END; /
The following example updates the list of projects assigned to one department:
-- Needs to be simplified... DECLARE new_projects ProjectList := ProjectList(Project(1, 'Issue New Employee Badges', 13500), Project(2, 'Inspect Emergency Exits', 1900), Project(3, 'Upgrade Alarm System', 3350), Project(4, 'Analyze Local Crime Stats', 825)); BEGIN UPDATE department SET projects = new_projects WHERE name = 'Security'; END; /
The next example retrieves a varray in a database table and stores it in a local varray:
-- Needs to be simplified... DECLARE my_projects ProjectList; BEGIN SELECT projects INTO my_projects FROM department WHERE name = 'Accounting'; END; /
Related Topics