Oracle8i Concepts
Release 8.1.5

A67781-01

Library

Product

Contents

Index

Prev Next

14
Using User-Defined Datatypes

It is not enough to have a good mind. The main thing is to use it well.

René Descartes, Le Discours de la Méthode

This chapter covers the main concepts you need to understand to use user-defined datatypes. It contains the following major sections:

Introduction

A data model for any application is comprised of entities, associations among these entities, and attributes that describe both the entities and the associations.

For example, a purchase-order application will likely include entities such as CUSTOMER, ORDER and LINE-ITEM. When a customer places an order consisting of several line items in the physical world, these relationships delineate associations among the entities in the data model. Each of these entities may have one or more attributes: the entity CUSTOMER may have an attribute such as CUSTOMER NAME and CUSTOMER ADDRESS; LINE-ITEMS may have attributes such as QUANTITY and PRICE; and so on.

The attributes themselves may be structured or multi-valued. For example, NAME may consist of FIRSTNAME and LASTNAME, while ADDRESS may be a composite of STREET, CITY, STATE and ZIP. Similarly, LINE-ITEMS may be a set of LINE-ITEMS.

In Oracle8i, release 8.1.x, you can define object types to model both entities and structured attributes of such entities. You can utilize collection types to model multi-valued attributes, and employ object references or a collection type of object references to model associations among entities. If you model an association using an object type which contains object references of the entities participating in the association, the attributes delineated in the object type will describe the association.

Object Types and References

This section describes object types and references, including:

Properties of Object Attributes

Oracle allows you to specify some properties of object attributes:

Nulls

One possible property of a table column, object, object attribute, collection, or collection element is that it can be null. This means that the item has been initialized to NULL or has been left uninitialized. Usually this means that the value of the item is not yet known but might become available later.

An object whose value is NULL is called atomically null. In addition, attributes of an object can be null. These two uses of nulls are different.

For example, consider the CONTACTS table defined as follows:

CREATE TYPE external_person AS OBJECT (
  name        VARCHAR2(30),
  phone       VARCHAR2(20) );

CREATE TABLE contacts (
  contact     external_person
  date        DATE );

The statement

INSERT INTO contacts VALUES (
  external_person (NULL, NULL),
 '24 Jun 1997' );

gives a different result from

INSERT INTO contacts VALUES (
  NULL,
 '24 Jun 1997' ); 

In both cases, Oracle allocates space in CONTACTS for a new row and sets its DATE column to the value given. In the first case, Oracle allocates space for an object in the EXTERNAL_PERSON column and sets each of its attributes to NULL. In the second case, it sets the EXTERNAL_PERSON column to NULL and does not allocate space for an object.

A table row cannot be null. Therefore, Oracle does not allow you to set a row object to NULL. Similarly, a nested table of objects cannot contain an element whose value is NULL.

A nested table or array can be null. A null collection is different from an empty one, that is, a collection containing no elements.

Defaults

When you declare a table column to be of an object type or collection type, you can include a DEFAULT clause. This provides a value to use in cases where you do not explicitly specify a value for the column. The default clause must contain a literal invocation of the constructor method for that object or collection.

A literal invocation of a constructor method is defined recursively to be an invocation of the constructor method in which any arguments are either literals or literal invocations of constructor methods.

For example, consider the following statements:

CREATE TYPE person AS OBJECT (
  id        NUMBER
  name      VARCHAR2(30),
  address   VARCHAR2(30) );

CREATE TYPE people AS TABLE OF person;

The following is a literal invocation of the constructor method for the nested table type PEOPLE:

people ( person(1, 'John Smith', '5 Cherry Lane'), 
         person(2, 'Diane Smith', NULL) )

The following example shows how to use literal invocations of constructor methods to specify defaults:

CREATE TABLE department (
  d_no    CHAR(5) PRIMARY KEY,
  d_name  CHAR(20),
  d_mgr   person DEFAULT person(1,'John Doe',NULL),
  d_emps  people DEFAULT people() )
  NESTED TABLE d_emps STORE AS d_emps_tab;

Note that the term PEOPLE( ) is a literal invocation of the constructor method for an empty PEOPLE table.

Constraints

You can define constraints on an object table just as you can on other tables.

You can define constraints on the leaf-level scalar attributes of a column object, with the exception of REFs that are not scoped (see "Scoped REFs").

The following examples illustrate the possibilities.

The first example places a primary key constraint on the SSNO column of the object table PERSON_EXTENT:

CREATE TYPE location (
  building_no NUMBER,
  city        VARCHAR2(40) );

CREATE TYPE person (
  ssno        NUMBER,
  name        VARCHAR2(100),
  address     VARCHAR2(100),
  office      location );

CREATE TABLE person_extent OF person (
  ssno        PRIMARY KEY );

The DEPARTMENT table in the next example has a column whose type is the object type LOCATION defined in the previous example. The example defines constraints on scalar attributes of the LOCATION objects that appear in the DEPT_LOC column of the table.

CREATE TABLE department (
  deptno      CHAR(5) PRIMARY KEY, 
  dept_name   CHAR(20),
  dept_mgr    person,
  dept_loc    location,
  CONSTRAINT  dept_loc_cons1
      UNIQUE (dept_loc.building_no, dept_loc.city),
  CONSTRAINT  dept_loc_cons2
       CHECK (dept_loc.city IS NOT NULL) );

Indexes

You can define indexes on an object table or on the storage table for a nested table column or attribute just as you can on other tables.

You can define indexes on leaf-level scalar attributes of column objects, except that you can only define indexes on REF attributes or columns if the REF is scoped (see "Scoped REFs").

The following example defines an index on an attribute of an object column:

CREATE TABLE department (
  deptno      CHAR(5) PRIMARY KEY, 
  dept_name   CHAR(20),
  dept_addr   address );

CREATE INDEX  i_dept_addr1
          ON  department (dept_addr.city);

This code creates an index on the city attribute of the department address.

Wherever Oracle expects a column name in an index definition, you can also specify a scalar attribute of an object column.

Triggers

You can define triggers on an object table just as you can on other tables. You cannot define a trigger on the storage table for a nested table column or attribute.

You cannot modify LOB values in a trigger body. Otherwise, there are no special restrictions on using user-defined types with triggers.

The following example defines a trigger on the PERSON_EXTENT table defined in an earlier section:

CREATE TABLE movement (
     ssno        NUMBER,
     old_office  location,
     new_office  location );

CREATE TRIGGER trig1
  BEFORE UPDATE
             OF  office
             ON  person_extent
   FOR EACH ROW
           WHEN  new.office.city = 'REDWOOD SHORES'
   BEGIN
     IF :new.office.building_no = 600 THEN
      INSERT INTO movement (ssno, old_office, new_office)
       VALUES (:old.ssno, :old.office, :new.office);
     END IF;
   END;

Object References

In Oracle, a REF column or attribute can be unconstrained or constrained using a SCOPE clause or a referential constraint clause. When a REF column is unconstrained, it may store object references to row objects contained in any object table of the corresponding object type.

Oracle does not ensure that the object references stored in such columns are valid in that they 'point' to valid and existing row objects. Therefore, REF columns may contain object references that do not 'point' to any existing row object. Such REF values are referred to as "dangling references". Currently, Oracle does not permit storing object references that contain a primary-key based OID in unconstrained REF columns.

A REF column may be constrained to be 'scoped' to a specific object table. All the REF values stored in a column with a SCOPE constraint 'point' at row objects of the table specified in the SCOPE clause. The REF values may, however, be 'dangling'.

A REF column may be constrained with a REFERENTIAL constraint similar to the specification for foreign keys. The rules for referential constraints apply to such columns. That is, the object reference stored in these columns must point to a valid and existing row object in the specified object table.

UNIQUE or PRIMARY KEY constraints may not be specified for REF columns. However, you may specify NOT NULL constraints for such columns.

Name Resolution

Oracle SQL is designed to be easy to use. For example, if PROJECTS is a table with a column called ASSIGNMENT, and DEPTS is a table that does not contain a column called ASSIGNMENT, you can write:

SELECT * 
FROM projects 
WHERE EXISTS
  (SELECT * FROM  depts
            WHERE assignment = task); 

Oracle determines which table each column belongs to. You can, but do not have to, qualify the column names with table names:

SELECT * 
FROM projects 
WHERE EXISTS
  (SELECT * FROM  depts
            WHERE projects.assignment = depts.task);

You can, but do not have to, qualify the column names with table aliases:

SELECT * 
FROM projects pj 
WHERE EXISTS
  (SELECT * FROM  depts dp
            WHERE pj.assignment = dp.task);

Table Aliases

The first form of the SELECT statement above is the easiest to write and understand, but it can lead to undesired results if you later add an ASSIGNMENT column to the DEPTS table and forget to change the query. Oracle automatically recompiles the query and the new version uses the ASSIGNMENT column from the DEPTS table. This situation is called inner capture.

In order to avoid inner capture and similar misinterpretations of the intended meanings of SQL statements, Oracle requires you to use table aliases to qualify references to methods or attributes of objects. This also applies to attribute references via REFs. This requirement is called the capture avoidance rule.

For example, consider the following statements:

CREATE TYPE person AS OBJECT (ssno VARCHAR(20));
CREATE TABLE ptab1 OF person;
CREATE TABLE ptab2 (c1 person);

These define an object type PERSON and two tables. The first is an object table for objects of type PERSON. The second has a single column of type PERSON.

Now consider the following queries:

SELECT      ssno FROM ptab1   ;  --Correct
SELECT   c1.ssno FROM ptab2   ;  --Wrong
SELECT p.c1.ssno FROM ptab2 p ;  --Correct

Qualifying references to object attributes with table names rather than table aliases, even if the table names are further qualified by schema names, does not satisfy this requirement.

For example, you cannot, in a query, use the expression

scott.projects.assignment.duedate

to refer to the DUEDATE attribute of the ASSIGNMENT column of the PROJECTS table of the SCOTT schema.

Table aliases should be unique throughout a query and should not be the same as schema names that could legally appear in the query.


Note:

Oracle recommends that you define table aliases in all UPDATE, DELETE, and SELECT statements and subqueries and use them to qualify column references, whether or not the columns contain object types.  


Method Calls without Arguments

Methods are functions or subroutines. The proper syntax for invoking them uses parentheses following the method name to enclose any calling arguments. In order to avoid ambiguities, Oracle requires empty parentheses for method calls that do not have arguments.

For example, if TB is a table with column C of object type T, and T has a method m that does not take arguments, the following query illustrates the correct syntax:

SELECT p.c.m() FROM tb p;

This differs from the rules for PL/SQL functions and procedures, where the parentheses are optional for calls that have no arguments.

Collections

This section describes the use of collections, including:

Querying Collections

In Oracle8i, a collection column may be queried using the TABLE expression. For example, a nested table column (PROJECTS) of the table (EMPLOYEES) can be queried as follows:

SELECT * FROM TABLE(SELECT t.projects FROM employees t WHERE t.eno = 1000);

SELECT t.eno, CURSOR(SELECT * FROM TABLE(t.projects)) FROM employees t;

The TABLE expression can be used to query any collection value expression including transient values such as variables and parameters.


Note:

The TABLE expression takes the place of THE subquery introduced in a previous release. The THE subquery expression will eventually be deprecated.  


Collection Unnesting

Many tools and applications are not equipped to deal with collection types, and require a flattened view of the data. In order to view collection data in an Oracle schema using these tools, the collection attribute of a row has to be unnested or flattened into one or more relational rows. Consider the following object-relational schema:

CREATE TYPE emp_set_t IS NESTED TABLE of emp_t;
CREATE TYPE dept_t(deptno NUMBER, emps emp_set_t);
CREATE TABLE depts OF dept_t NESTED TABLE emps STORE AS depts_emps;

The following query results in the data in the EMPS column being unnested with respect to the DEPT table in that every row of EMPS is augmented with its parent DEPTS row:

SELECT d.deptno, e.* FROM depts d, TABLE(d.emps) e;

Oracle8i also supports the following syntax to produce outer-join results:

SELECT d.*, e.* FROM depts d, TABLE(d.emps)(+) e;

The (+) indicates that the 'dependent' join between DEPTS and D.EMPS should be NULL-augmented. That is, there will be rows of DEPTS in the output for which D.EMPS is NULL or empty, with NULL values for columns corresponding to D.EMPS.

Nested Table Locators

In Oracle8i, the collection typed value is encapsulated. Consequently, a client must access the contents of a collection via interfaces provided by Oracle.

Generally, when the client accesses a nested table explicitly or implicitly (by fetching the containing object), Oracle returns the entire collection value to the client process. However, for performance reasons, a client may wish to control when the elements of a collection are to be materialized on the client side, if at all. This is especially relevant when the collection value is very large. To facilitate this kind of operation, Oracle supports the ability to return a nested table value as a locator.

A nested table locator is like a handle to the collection value. It attempts to preserve the value or copy semantics of the nested table by containing the database snapshot as of its time of retrieval. The snapshot helps the database retrieve the correct instantiation of the nested table value at a later time when the collection elements are fetched using the locator. The locator is scoped to a session and cannot be used across sessions. Since database snapshots are used, it is possible to get a "snapshot too old" error if there is a high update rate on the nested table. Unlike a LOB locator, the nested table locator is truly a locator and cannot be used to modify the collection instance.

DML on Collections

Oracle supports the following DML operations on nested table columns

Oracle does not support piecewise updates on VARRAY columns. However, VARRAY columns can be inserted into or updated as an atomic unit.

For piecewise updates of nested table columns, the DML statement identifies the nested table value to be operated on by using the TABLE expression. Note that DML operations on a nested table value are serialized. That is, when a nested table value is operated on by a DML statement in a transaction, modifications to the same nested table value from other transactions are blocked until after the transaction terminates.

The following DML statements demonstrate piecewise operations on nested table columns.

INSERT INTO TABLE(SELECT e.projects
                  FROM       employees e
                  WHERE      e.eno = 100)
   VALUES (1, `Project Neptune');

UPDATE TABLE(SELECT e.projects
                 FROM        employees e
                 WHERE       e.eno = 100) p
   SET VALUE(p) = project_t(1, `Project Pluto')
   WHERE p.pno = 1;

DELETE FROM TABLE(SELECT e.projects
                  FROM        employee e
                  WHERE       e.eno = 100) p
   WHERE p.pno = 1;

Privileges on User-Defined Types and Their Methods

Privileges for user-defined types exist at the system level and schema object level.

System Privileges

Oracle defines the following system privileges for user-defined types:

The CONNECT and RESOURCE roles include the CREATE TYPE system privilege. The DBA role includes all of the above privileges.

Schema Object Privileges

The only schema object privilege that applies to user-defined types is EXECUTE.

EXECUTE on a user-defined type allows you to use the type to:

EXECUTE lets you invoke the type's methods, including the constructor.

Method execution and the associated permissions are the same as for stored PL/SQL procedures.

Using Types in New Types or Tables

In addition to the permissions detailed in the previous sections, you need specific privileges to:

You must have the EXECUTE ANY TYPE system privilege, or you must have the EXECUTE object privilege for any type you use in defining a new type or table. You must have received these privileges explicitly, not through roles.

If you intend to grant access to your new type or table to other users, you must have either the required EXECUTE object privileges with the GRANT option or the EXECUTE ANY TYPE system privilege with the option WITH ADMIN OPTION. You must have received these privileges explicitly, not through roles.

Example

Assume that three users exist with the CONNECT and RESOURCE roles: USER1, USER2, and USER3.

USER1 performs the following DDL in the USER1 schema:

CREATE TYPE type1 AS OBJECT ( attr1 NUMBER );
CREATE TYPE type2 AS OBJECT ( attr2 NUMBER );
GRANT EXECUTE ON type1 TO user2;
GRANT EXECUTE ON type2 TO user2 WITH GRANT OPTION;

USER2 performs the following DDL in the USER2 schema:

CREATE TABLE tab1 OF user1.type1;
CREATE TYPE type3 AS OBJECT ( attr3 user1.type2 );
CREATE TABLE tab2 (col1 user1.type2 );

The following statements succeed, because USER2 has EXECUTE on USER1's TYPE2 with the GRANT option:

GRANT EXECUTE ON type3 TO user3;
GRANT SELECT on tab2 TO user3;

However, the following grant fails, because USER2 does not have EXECUTE on USER1.TYPE1 with the GRANT option:

GRANT SELECT ON tab1 TO user3;

USER3 can successfully perform the following actions:

CREATE TYPE type4 AS OBJECT (attr4 user2.type3);
CREATE TABLE tab3 OF type4;

Privileges on Type Access and Object Access

The privileges that regulate use of tables apply equally to object tables:

Similar table and column privileges regulate the use of table columns of user-defined types.

Selecting columns of an object table does not require privileges on the type of the object table. Selecting the entire row object, however, does.

Consider the following schema:

CREATE TYPE emp_type as object (
  eno    NUMBER,
  ename  CHAR(31),
  eaddr  addr_t );

CREATE TABLE emp OF emp_type;

and the following two queries:

SELECT VALUE(e) FROM emp e;
SELECT eno, ename FROM emp;

For either query, Oracle checks the user's SELECT privilege for the EMP table. For the first query, the user needs to obtain the EMP_TYPE type information to interpret the data. When the query accesses the EMP_TYPE type, Oracle checks the user's EXECUTE privilege.

Execution of the second query, however, does not involve named types, so Oracle does not check type privileges.

Additionally, using the schema from the previous section, USER3 can perform the following queries:

SELECT tab1.col1.attr2 from user2.tab1 tab1;
SELECT t.attr4.attr3.attr2 FROM tab3 t;

Note that in both selects by USER3, USER3 does not have explicit privileges on the underlying types, but the statement succeeds because the type and table owners have the necessary privileges with the GRANT option.

Oracle checks privileges on the following requests, and returns an error if the requestor does not have the privilege for the action:

Oracle does not provide column level privileges for object tables.

Dependencies and Incomplete Types

Types can depend upon each other for their definitions. For example, you might want to define object types EMPLOYEE and DEPARTMENT in such a way that one attribute of EMPLOYEE is the department the employee belongs to and one attribute of DEPARTMENT is the employee who manages the department.

Types that depend on each other in this way, either directly or via intermediate types, are called mutually dependent. A diagram of mutually dependent types, with arrows representing the dependencies, always reveals a path of arrows starting and ending at one of the types.

Oracle allows such cyclic dependencies only when at least one branch of the cycle uses REFs.

For example, you can define the following types:

CREATE TYPE department;

CREATE TYPE employee AS OBJECT (
  name    VARCHAR2(30),
  dept    REF department,
  supv    REF employee );

CREATE TYPE emp_list AS TABLE OF employee;

CREATE TYPE department AS OBJECT (
  name    VARCHAR2(30),
  mgr     REF employee,
  staff   emp_list );

This is a legal set of mutually dependent types and a legal sequence of SQL DDL statements. Oracle compiles it without errors. The first statement:

CREATE TYPE department;

is optional. It makes the compilation proceed without errors. It establishes DEPARTMENT as an incomplete object type. A REF to an incomplete object type compiles without error, so the compilation of EMPLOYEE proceeds.

When Oracle reaches the last statement, which completes the definition of DEPARTMENT, all of the components of DEPARTMENT have compiled successfully, so the compilation finishes without errors.

Without the optional declaration of DEPARTMENT as an incomplete type, EMPLOYEE compiles with errors. Oracle then automatically adds EMPLOYEE to its library of schema objects as an incomplete object type. This makes the declarations of EMP_LIST and DEPARTMENT compile without errors. When EMPLOYEE is recompiled after EMP_LIST and DEPARTMENT are complete, EMPLOYEE compiles without errors and becomes a complete object type.

Completing Incomplete Types

Once you have declared an incomplete object type, you must complete it as an object type. You cannot, for example, declare it to be a table type or an array type. The only alternative is to drop the type.

This is also true if Oracle has made the type an incomplete object type for you--as it did when EMPLOYEE failed to compile in the previous section.

Type Dependencies of Tables

The SQL commands REVOKE and DROP TYPE return an error and abort if the type referred to in the command has tables or other types that depend on it.

The FORCE option with either of these commands overrides that behavior. The command succeeds and the affected tables or types become invalid.

If a table contains data that relies on a type definition for access, any change to the type causes the table's data to become inaccessible. This happens if privileges required by the type are revoked or if the type or a type it depends on is dropped. The table then becomes invalid and cannot be accessed.

A table that is invalid because of missing privileges automatically becomes valid and accessible if the required privileges are re-granted.

A table that is invalid because a type it depends on has been dropped can never be accessed again. The only permissible action is to drop the table.

Storage of User-Defined Types

Oracle stores and manages data of user-defined types in tables. It automatically maps the complex structure of user-defined types into the simple rectangular structure of tables.

Leaf-Level Attributes

The structure of an object type is like a tree. The branches that grow from the trunk go to the attributes. If an attribute is of an object type, that branch sprouts subbranches for the attributes of the new object type.

Ultimately, each branch comes to an end at an attribute that is of a built-in type or a collection type. These are called leaf-level attributes of the original object type. Oracle provides a table column for each leaf-level attribute.

The leaf-level attributes that not collection types are called the leaf-level scalar attributes of the object type.

Row Objects

In an object table, every leaf-level scalar or REF attribute has a column in which Oracle stores its actual data. This is also true of VARRAYs, unless they are too large (see "VARRAYs"). Oracle stores leaf-level attributes of table types in separate tables associated with the object table. You must declare these tables as part of the object table declaration (see "Nested Tables").

Access to individual attributes of objects in an object table is simply access to columns of the table. Accessing the value of the object itself causes Oracle to invoke the default constructor for the type, using the columns of the object table as arguments. That is, Oracle supplies a copy of the object.

Oracle stores the system-generated object identifier in a hidden column. Oracle uses the object identifier to construct REFs to the object.

Column Objects

When a table is defined with a column of an object type, Oracle adds hidden columns to the table for the object type's leaf-level attributes. An additional column stores the NULL information of the object (that is, the atomic nulls of the top-level and the nested objects).

REFs

Oracle constructs a REF to a row object by invoking the built-in function REF on the row object. The constructed REF is made up of the object identifier, some metadata of the object table, and, optionally, the ROWID.

The size of a REF in a column of REF type depends on the storage properties associated with the column. For example, if the column is declared as a REF WITH ROWID, Oracle stores the ROWID in the REF column. The ROWID hint is ignored for object references in constrained REF columns.

If column is declared as a REF with a SCOPE clause, then Oracle does not store the object table metadata and the ROWID in the column. A scoped REF is 16 bytes long.

Oracle8i stores unconstrained REF values in a single column. If a REF column is scoped or referentially constrained to an object table with a system-generated OID, Oracle creates a single column to store the OID value. However, if the OID is primary-key based, then Oracle may create one or more internal columns to store the values of the primary key depending on how many columns comprise the primary key. References to row objects containing primary key based OIDs may only be stored in REF columns with scoped or referential constraints.

Nested Tables

The rows of a nested table are stored in a separate storage table. For each nested table column, the associated storage table contains the elements of all instances of the nested table (in all rows of the parent table). The storage table has a hidden NESTED_TABLE_ID column that stores a system-generated value used by Oracle to identify the rows of a particular nested table value.

Oracle allows the storage table to be an index-organized table. The index-only organization of the storage table allows for the clustering of all rows of a nested table value.

Oracle supports two forms of element types for a nested table type:

If the type of the element is an object type, the storage table is very similar to an object table in that the top-level attributes of the object type become the columns of the storage table. One notable exception is that there is no OID column since there is no OID value associated with a nested table row. Consequently, objects in a nested table are not referenceable.

The storage table for a nested table whose element type is a scalar contains a single column called COLUMN_VALUE which contains the values of the scalar.

VARRAYs

All the elements of a VARRAY are stored in a single column. If the size of the array is smaller than 4000 bytes, Oracle stores it inline; if it is greater than 4000 bytes, Oracle stores it in a BLOB.

Utilities

Oracle provides several methods for moving and loading data within Oracle databases.

Import/Export of User-Defined Types

The Export and Import utilities move data into and out of Oracle databases. They also back up or archive data and aid migration to different releases of the Oracle RDBMS.

Export and Import support user-defined types. Export writes user-defined type definitions and all of the associated data to the dump file. Import then re-creates these items from the dump file.

Additional Information:

See Oracle8i Utilities for more information about Export and Import.  

Loading User-defined Types

The SQL*Loader supports loading row objects, column objects and objects with collections and references. In Oracle8i, only conventional path loading is supported for objects.

Additional Information:

See Oracle8i Utilities for more information about SQL*Loader.  




Prev

Next
Oracle
Copyright © 1999 Oracle Corporation.

All Rights Reserved.

Library

Product

Contents

Index