Oracle8 Concepts Release 8.0 A58227-01 |
|
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:
Attention: The features described in this chapter are available only if you have purchased Oracle8 Enterprise Edition with the Objects Option. See Getting to Know Oracle8 and the Oracle8 Enterprise Edition for information about the features and options available with Oracle8 Enterprise Edition. |
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 don't 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 don't have to, qualify the column names with table aliases:
SELECT * FROM projects pj WHERE EXISTS (SELECT * FROM depts dp WHERE pj.assignment = dp.task);
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
ssno
is the name of a column of ptab1
. No further qualification is required.
ssno
is the name of an attribute of the person
object in the column named c1
. This reference requires a table alias.
p
.
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.
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.
Oracle stores and manages data of user-defined types in tables. It automatically and invisibly maps the complex structure of user-defined types into the simple rectangular structure of tables.
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.
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" on page 12-5). 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" on page 12-5).
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.
When a table is defined with a column of an object type, Oracle invisibly adds 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).
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. An unscoped REF with ROWID to an object in an object table is 46 bytes in size. REFs to object views, REFs without ROWID, and scoped REFs are smaller.
The ROWID in a REF is used as a hint for efficient access. When Oracle dereferences a REF item, it uses the ROWID to choose a row; if the object identifier of the identified row matches the one in the REF, the access is successful. Otherwise, Oracle uses the index on the object identifier to identify the correct row.
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; otherwise, it discards the ROWID.
If column is declared as 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.
The rows of a nested table are stored in a separate storage table. You must supply a storage tablename when you define the table containing the nested table. If the table definition contains more than one table type - either in columns or in object types that appear in column definitions - you must supply a separate storage table for each.
For each nested table in the table definition, the associated storage table contains the rows of all instances of the given nested table in the rows of the parent table.
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 in line; if it is greater than 4000 bytes, Oracle stores it in a BLOB.
Oracle allows you to specify some properties of object attributes:
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.
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.
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" on page 11-8).
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) );
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" on page 11-8).
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.
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 the values of collections (or LOBs) in the code that defines a trigger action. 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;
Privileges for user-defined types exist at the system level and schema object level.
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.
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.
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.
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;
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.
Retrieving data of user-defined types does not require type information. Interpreting the data, however, does require such information. When Oracle receives requests for type information, it verifies that the requestor has EXECUTE privilege on the type before supplying the requested information.
Consider the following schema:
CREATE TYPE emp_type ( 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.
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.
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.
This restriction applies even if there are no REFs to the incomplete object type anywhere in the schema. The rule Oracle follows is that once it flags a type as the potential target of REFs, that type must remain a potential REF target until it is dropped.
Oracle recognizes only object types as potential REF targets.
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.
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.
The Export and Import utilities move data into and out of Oracle databases. They are 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, foreign function library definitions, directory alias definitions, and all of the associated data to the dump file. Import then recreates these items from the dump file.