Skip to main content

PL/SQL 201: When do I have to create a schema-level type?

I received this question in my In Box last week:

In your PL/SQL 101: Working with Collections article in Oracle Magazine, the use of "TYPE ... IS ..." is demonstrated.  However I found it's not possible to instantiate an object of the TYPE. It seems that the use of "CREATE TYPE ... AS OBJECT" is required. What are the differences between the 2 ways of creating a user defined data type? 

Yes, it can certainly be  confusing when you use the same TYPE statement for arrays and object types, but they cannot all be used in all the same ways in all the same places.

So let's go over the differences.

PL/SQL

Within PL/SQL, you use the TYPE statement to define two different, ahem, types of user-defined types: record and collection.

Record

A composite datatype consisting of one of more fields. Each field may be of almost any PL/SQL datatype, including another record type or a collection type.

You can use the TYPE statement to define a new record type in any declaration section of a PL/SQL block, including a package.

Here are some examples:

create or replace package my_types
is
   type two_fields_rt is record (
      field1 number, 
      field2 date);
end;
/

declare
   type two_fields_rt is record (
      field1 number, 
      field2 date);
   
   l_record1 two_fields_rt;   
   l_record2 my_types.two_fields_rt;
begin
   l_record1.field1 := 100;
end;
/

Collection

Collections are PL/SQL's versions of arrays. There are different sorts: associative array, nested table and varray. When you define a collection you define the type of data that can be sorted in the collection.

You can use the TYPE statement to define a new collection type in any declaration section of a PL/SQL block, including a package.

Here are some examples:

create or replace package my_types
is
   type two_fields_rt is record (
      field1 number, 
      field2 date);

   type assoc_array_t is table of two_fields_rt
      index by pls_integer;

   type mested_table_t is table of two_fields_rt;

   type varray_t is varray(10) of two_fields_rt;
end;
/

declare
   type assoc_array_t is table of two_fields_rt
      index by pls_integer;
   
   l_list1 assoc_array_t;
   l_list2 my_types.assoc_array_t;
   l_list3 my_types.varray_t;
begin
   l_list1 (100).field1 := 100;
end;
/

You may not, however, declare an object type inside a PL/SQL block. Like a relational table, object types must be defined at the schema level, as a database object, using a SQL DDL statemeant.

SQL

Within SQL, you use the CREATE TYPE DDL statement to define two different, ahem, types of user-defined types: collection and object. You cannot define a record type in SQL.

Collection

SQL implements two types of collections as part of its object model: nested table and varray. When you define a collection you define the type of data that can be sorted in the collection.

Here are some examples:

create or replace type nested_table_t is table of number
/

create or replace type varray_t is varray(10) of date
/

declare
   l_list1 nested_table_t := nested_table_t (1, 2, 3);
   l_list2 varray_t;
begin
   l_list1 (1) := 100;
end;
/

Object

Within SQL, you can also use CREATE TYPE to define an object type, which is Oracle's "version" of a class for object-oriented development.

create or replace type food_t is object (
   name varchar2(100),
   grown_in varchar2(100),
   food_category varchar2(30)
)
/

declare
   l_food food_t := food_t (
      'Brussels Sprouts', 'Soil', 'Vegetable');
begin
   l_food.grown_in := 'Sandy Soil';
end;
/

Even though you create an object type in the database just like a relational table (and the syntax is very similar), an object type is really just a "template" for declaring instances of the type, while a table is a container for data.

You can have a table of object types:

create table our_food (your_food food_t, my_food food_t)

But you cannot declare an object type within a PL/SQL block, for "temporary" use inside that block. Instead, declare a record type.


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