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.
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:
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:
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.
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.
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;
/
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
Post a Comment