PK
-Aoa, mimetypeapplication/epub+zipPK -A iTunesMetadata.plistX
This chapter shows how to write object-oriented applications without changing the underlying structure of your relational data.
The chapter contains these topics:
Just as a view is a virtual table, an object view is a virtual object table. Each row in the view is an object: you can call its methods, access its attributes using the dot notation, and create a REF
that points to it.
You can run object-oriented applications without converting existing tables to a different physical structure. To do this, you can use object views to prototype or transition to object-oriented applications because the data in the view can be taken from relational tables and accessed as if the table were defined as an object table.
Object views can be used like relational views to present only the data that you want users to see. For example, you might create an object view that presents selected data from an employee table but omits sensitive data about salaries.
Using object views can lead to better performance. Relational data that makes up a row of an object view traverses the network as a unit, potentially saving many round trips.
You can fetch relational data into the client-side object cache and map it into C structures or C++ or Java classes, so 3GL applications can manipulate it just like native classes. You can also use object-oriented features like complex object retrieval with relational data.
You can query the data in new ways by synthesizing objects from relational data. You can view data from multiple tables by using object dereferencing instead of writing complex joins with multiple tables.
You can pin the object data from object views and use the data in the client side object cache. When you retrieve these synthesized objects in the object cache by means of specialized object-retrieval mechanisms, you reduce network traffic.
You gain great flexibility when you create an object model within a view, enabling you to continue developing the model. If you need to alter an object type, you can simply replace the invalidated views with a new definition.
You do not place any restrictions on the characteristics of the underlying storage mechanisms by using objects in views. By the same token, you are not limited by the restrictions of current technology. For example, you can synthesize objects from relational tables which are parallelized and partitioned.
You can create different complex data models from the same underlying data.
See Also:
|
The procedure for defining an object view is:
Define an object type, where each attribute of the type corresponds to an existing column in a relational table.
Write a query that specifies how to extract the data from the relational table. Specify the columns in the same order as the attributes in the object type.
Specify a unique value, based on attributes of the underlying data, to serve as an object identifier, enabling you to create pointers (REF
s) to the objects in the view. You can often use an existing primary key.
To update an object view where the attributes of the object type do not correspond exactly to columns in existing tables, you may need to do the following:
Write an INSTEAD
OF
trigger procedure for Oracle to execute whenever an application program tries to update data in the object view. See "Updating Object Views".
After these steps, you can use an object view just like an object table.
Example 6-1 contains SQL statements to define an object view, where each row in the view is an object of type employee_t
:
Example 6-1 Creating an Object View
CREATE TABLE emp_table (
empnum NUMBER (5),
ename VARCHAR2 (20),
salary NUMBER (9,2),
job VARCHAR2 (20));
CREATE TYPE employee_t AS OBJECT (
empno NUMBER (5),
ename VARCHAR2 (20),
salary NUMBER (9,2),
job VARCHAR2 (20));
/
CREATE VIEW emp_view1 OF employee_t
WITH OBJECT IDENTIFIER (empno) AS
SELECT e.empnum, e.ename, e.salary, e.job
FROM emp_table e
WHERE job = 'Developer';
insert into emp_table values(1,'John',1000.00,'Architect');
insert into emp_table values(2,'Robert',900.00,'Developer');
insert into emp_table values(3,'James',2000.00,'Director');
select * from emp_view1;
EMPNO ENAME SALARY JOB
---------- -------------------- ---------- --------------------
2 Robert 900 Developer
To access the data from the empnum
column of the relational table, access the empno
attribute of the object type.
Data in the rows of an object view may come from more than one table, but the object view still traverses the network in one operation. The instance appears in the client side object cache as a C or C++ structure or as a PL/SQL object variable. You can manipulate it like any other native structure.
You can refer to object views in SQL statements in the same way you refer to an object table. For example, object views can appear in a SELECT
list, in an UPDATE-SET
clause, or in a WHERE
clause.
You can also define object views on object views.
You can access object view data on the client side using the same OCI calls you use for objects from object tables. For example, you can use OCIObjectPin()
for pinning a REF
and OCIObjectFlush()
for flushing an object to the server. When you update or flush an object to the database in an object view, the database updates the object view.
An object type can have other object types nested in it as attributes.
If the object type on which an object view is based has an attribute that itself is an object type, then you must provide column objects for this attribute as part of the process of creating the object view. If column objects of the attribute type already exist in a relational table, you can simply select them; otherwise, you must synthesize the object instances from underlying relational data just as you synthesize the principal object instances of the view. You synthesize, or create, these objects by calling the respective constructor methods of the object type to create the object instances, and you can populate their attributes with data from relational columns specified in the constructor.
For example, consider the department table dept
in Example 6-2. You might want to create an object view where the addresses are objects inside the department objects. That would allow you to define reusable methods for address objects, and use them for all kinds of addresses.
First, create the types for the address and department objects, then create the view containing the department number, name and address. The address
objects are constructed from columns of the relational table.
Example 6-2 Creating a View with Nested Object Types
CREATE TABLE dept (
deptno NUMBER PRIMARY KEY,
deptname VARCHAR2(20),
deptstreet VARCHAR2(20),
deptcity VARCHAR2(10),
deptstate CHAR(2),
deptzip VARCHAR2(10));
CREATE TYPE address_t AS OBJECT (
street VARCHAR2(20),
city VARCHAR2(10),
state CHAR(2),
zip VARCHAR2(10));
/
CREATE TYPE dept_t AS OBJECT (
deptno NUMBER,
deptname VARCHAR2(20),
address address_t );
/
CREATE VIEW dept_view OF dept_t WITH OBJECT IDENTIFIER (deptno) AS
SELECT d.deptno, d.deptname,
address_t(d.deptstreet,d.deptcity,d.deptstate,d.deptzip) AS
deptaddr
FROM dept d;
insert into dept values(1,'Sales','500 Oracle pkwy','Redwood S','CA','94065');
insert into dept values(2,'ST','400 Oracle Pkwy','Redwood S','CA','94065');
insert into dept values(3,'Apps','300 Oracle pkwy','Redwood S','CA','94065');
select * from dept_view;
DEPTNO DEPTNAME
---------- --------------------
ADDRESS(STREET, CITY, STATE, ZIP)
----------------------------------------------------------------------------------
1 Sales
ADDRESS_T('500 Oracle pkwy', 'Redwood S', 'CA', '94065')
2 ST
ADDRESS_T('400 Oracle Pkwy', 'Redwood S', 'CA', '94065')
3 Apps
ADDRESS_T('300 Oracle pkwy', 'Redwood S', 'CA', '94065')
Because the constructor for an object never returns a null, none of the address objects in the preceding view can ever be null, even if the city, street, and so on columns in the relational table are all null. The relational table has no column that specifies whether or not the department address is null.
By using the DECODE
function, or some other function, to return either a null or the constructed object, the null deptstreet
column can be used to indicate that the whole address is null.
Example 6-3 Identifying Null Objects in an Object View
-- Requires Ex. 6-2 CREATE OR REPLACE VIEW dept_view AS SELECT d.deptno, d.deptname, DECODE(d.deptstreet, NULL, NULL, address_t(d.deptstreet, d.deptcity, d.deptstate, d.deptzip)) AS deptaddr FROM dept d;
This technique makes it impossible to directly update the department address through the view, because it does not correspond directly to a column in the relational table. Instead, define an INSTEAD
OF
trigger over the view to handle updates to this column.
Collections, both nested tables and VARRAY
s, can be columns in views. You can select these collections from underlying collection columns or you can synthesize them using subqueries. The CAST-MULTISET
operator provides a way of synthesizing such collections.
This section contains the following topics:
Using Example 6-1 and Example 6-2 as starting points, each employee in an emp
relational table has the structure in Example 6-4. Using this relational table, you can construct a dept_view
with the department number, name, address and a collection of employees belonging to the department.
First, define a nested table type for the employee type employee_t
. Next, define a department type with a department number, name, address, and a nested table of employees. Finally, define the object view dept_view
.
Example 6-4 Creating a View with a Single-Level Collection
-- Requires Ex. 6-1 and Ex. 6-2 CREATE TABLE emp ( empno NUMBER PRIMARY KEY, empname VARCHAR2(20), salary NUMBER, job VARCHAR2 (20), deptno NUMBER REFERENCES dept(deptno)); CREATE TYPE employee_list_t AS TABLE OF employee_t; -- nested table / CREATE TYPE dept_t AS OBJECT ( deptno NUMBER, deptname VARCHAR2(20), address address_t, emp_list employee_list_t); / CREATE VIEW dept_view OF dept_t WITH OBJECT IDENTIFIER (deptno) AS SELECT d.deptno, d.deptname, address_t(d.deptstreet,d.deptcity,d.deptstate,d.deptzip) AS deptaddr, CAST( MULTISET ( SELECT e.empno, e.empname, e.salary, e.job FROM emp e WHERE e.deptno = d.deptno) AS employee_list_t) AS emp_list FROM dept d; insert into dept values(100,'ST','400 Oracle Pkwy','Redwood S','CA',94065); insert into dept values(200,'Sales','500 Oracle Pkwy','Redwood S','CA',94065); insert into emp values(1,'John',900,'Developer1',100); insert into emp values(2,'Robert',1000,'Developer2',100); insert into emp values(3,'Mary', 1000,'Apps1',200); insert into emp values(4,'Maria',1500,'Developer3',200); select * from dept_view where deptno = 100; DEPTNO DEPTNAME ---------- -------------------- ADDRESS(STREET, CITY, STATE, ZIP) -------------------------------------------------------------------------------- EMP_LIST(EMPNO, ENAME, SALARY, JOB) -------------------------------------------------------------------------------- 100 ST ADDRESS_T('400 Oracle Pkwy', 'Redwood S', 'CA', '94065') EMPLOYEE_LIST_T(EMPLOYEE_T(1, 'John', 900, 'Developer1'), EMPLOYEE_T(2, 'Robert' , 1000, 'Developer2')) select emp_list from dept_view where deptno = 100; EMP_LIST(EMPNO, ENAME, SALARY, JOB) -------------------------------------------------------------------------------- EMPLOYEE_LIST_T(EMPLOYEE_T(1, 'John', 900, 'Developer1'), EMPLOYEE_T(2, 'Robert' , 1000, 'Developer2'))
The SELECT
subquery inside the CAST-MULTISET
block selects the list of employees that belong to the current department. The MULTISET
keyword indicates that this is a list as opposed to a singleton value. The CAST
operator casts the result set into the appropriate type, in this case to the employee_list_t
nested table type.
A query on this view could provide the list of departments, with each department row containing the department number, name, the address object and a collection of employees belonging to the department.
Multilevel collections and single-level collections are created and used in object views in the same way. The only difference is that, for a multilevel collection, you must create an additional level of collections.
Example 6-5 builds an object view containing a multilevel collection. The view is based on flat relational tables that contain no collections. As a preliminary to building the object view, the example creates the object and collection types it uses. An object type (for example, emp_t
) is defined to correspond to each relational table, with attributes whose types correspond to the types of the respective table columns. In addition, the employee type has a nested table (attribute) of projects, and the department type has a nested table (attribute) of employees. The latter nested table is a multilevel collection. The CAST-MULTISET
operator is used in the CREATE
VIEW
statement to build the collections.
Example 6-5 Creating a View with Multilevel Collections
CREATE TABLE depts ( deptno NUMBER, deptname VARCHAR2(20)); CREATE TABLE emps ( ename VARCHAR2(20), salary NUMBER, deptname VARCHAR2(20)); CREATE TABLE projects ( projname VARCHAR2(20), mgr VARCHAR2(20)); CREATE TYPE project_t AS OBJECT ( projname VARCHAR2(20), mgr VARCHAR2(20)); / CREATE TYPE nt_project_t AS TABLE OF project_t; / CREATE TYPE emp_t AS OBJECT ( ename VARCHAR2(20), salary NUMBER, deptname VARCHAR2(20), projects nt_project_t ); / CREATE TYPE nt_emp_t AS TABLE OF emp_t; / CREATE TYPE depts_t AS OBJECT ( deptno NUMBER, deptname VARCHAR2(20), emps nt_emp_t ); / CREATE VIEW v_depts OF depts_t WITH OBJECT IDENTIFIER (deptno) AS SELECT d.deptno, d.deptname, CAST(MULTISET(SELECT e.ename, e.salary, e.deptname, CAST(MULTISET(SELECT p.projname, p.mgr FROM projects p WHERE p.mgr = e.ename) AS nt_project_t) FROM emps e WHERE e.deptname = d.deptname) AS nt_emp_t) FROM depts d;
You can construct pointers (REF
s) to the row objects in an object view. Because the view data is not stored persistently, you must specify a set of distinct values to be used as object identifiers. Object identifiers allow you to reference the objects in object views and pin them in the object cache.
If the view is based on an object table or an object view, then there is already an object identifier associated with each row and you can reuse them. To do this, either omit the WITH
OBJECT
IDENTIFIER
clause or specify WITH
OBJECT
IDENTIFIER
DEFAULT
.
However, if the row object is synthesized from relational data, you must choose some other set of values.
You can specify object identifiers based on the primary key. This turns the set of unique keys that identify the row object into an identifier for the object. These values must be unique within the rows selected out of the view, because duplicates would lead to problems during navigation through object references.
See Also: "Using Object Identifiers to Identify Row Objects" for a description of primary-key based and system-generated object identifiers |
Object views created with the WITH
OBJECT
IDENTIFIER
Clause
An object view created with the WITH
OBJECT
IDENTIFIER
clause has an object identifier derived from the primary key.
For example, note the definition of the object type dept_t
and the object view dept_view
described in "Single-Level Collections in Object Views".
Because the underlying relational table has deptno
as the primary key, each department row has a unique department number. In the view, the deptno
column becomes the deptno
attribute of the object type. Once you know that deptno
is unique within the view objects, you can specify it as the object identifier.
Object views created with the WITH
OBJECT
IDENTIFIER
DEFAULT
Clause
If the WITH
OBJECT
IDENTIFIER
DEFAULT
clause is specified, the object identifier is either system-generated or primary-key based, depending on the underlying table or view definition.
In this connected group of examples, Example 6-2 and Example 6-4, each object selected out of the dept_view
view has a unique object identifier derived from the department number value. In the relational case, the foreign key deptno
in the emp
employee table matches the deptno
primary key value in the dept
department table. The primary key value creates the object identifier in the dept_view
, allowing the foreign key value in the emp_view
to create a reference to the primary key value in dept_view
.
To synthesize a primary key object reference, use the MAKE_REF
operator. This takes the view or table name that the reference points to, and a list of foreign key values, to create the object identifier portion of the reference that matches a specific object in the referenced view.
Example 6-6 creates an emp_view
view which has the employee's number, name, salary and a reference to the employee's department, by first creating the employee type emp_t
and then the view based on that type.
Example 6-6 Creating a Reference to Objects in a View
-- Requires Ex. 6-2 and Ex. 6-4 -- if you have previously created emp_t, you must drop it CREATE TYPE emp_t AS OBJECT ( empno NUMBER, ename VARCHAR2(20), salary NUMBER, deptref REF dept_t); / CREATE OR REPLACE VIEW emp_view OF emp_t WITH OBJECT IDENTIFIER(empno) AS SELECT e.empno, e.empname, e.salary, MAKE_REF(dept_view, e.deptno) FROM emp e;
The deptref
column in the view holds the department reference. The following simple query retrieves all employees whose departments are located in the city of Redwood S:
SELECT e.empno, e.salary, e.deptref.deptno FROM emp_view e WHERE e.deptref.address.city = 'Redwood S'; EMPNO SALARY DEPTREF.DEPTNO ---------- ---------- -------------- 2 1000 100 1 900 100 4 1500 200 3 1000 200
Note that you can also create emp_view
using the REF
modifier instead of MAKE_REF
as follows to get the reference to the dept_view
objects:
Example 6-7 Query References to Objects with REF
-- Requires Ex. 6-2, Ex. 6-4, and Ex. 6-6
CREATE OR REPLACE VIEW emp_view OF emp_t WITH OBJECT IDENTIFIER(empno)
AS SELECT e.empno, e.empname, e.salary, REF(d)
FROM emp e, dept_view d
WHERE e.deptno = d.deptno;
In Example 6-7, the dept_view
joins the emp
table on the deptno
key.
The advantage of using the MAKE_REF
operator, as in Example 6-6, instead of the REF
modifier is that with the former, you can create circular references. For example, you can create an employee view that has a reference to the employee's department, while the department view has a list of references to the employees who work in that department.
Note that if the object view has a primary-key based object identifier, the reference to such a view is primary-key based. On the other hand, a reference to a view with system-generated object identifier is a system-generated object reference. This difference is only relevant when you create object instances in the OCI object cache and need to get the reference to the newly created objects.
As with synthesized objects, you can also select persistently stored references as view columns and use them seamlessly in queries. However, the object references to view objects cannot be stored persistently.
You can use views with objects to model inverse relationships.
One-to-one relationships can be modeled with inverse object references. For example, suppose that each employee has a particular desktop computer, and that the computer belongs to that employee only. A relational model would capture this using foreign keys either from the computer table to the employee table, or in the reverse direction. Using views, you can model the objects so there is an object reference from the employee to the computer object and also a reference from the computer object to the employee.
One-to-Many and Many-to-One Relationships
One-to-many relationships (or many-to-many relationships) can be modeled either by using object references or by embedding the objects. One-to-many relationship can be modeled by having a collection of objects or object references. The many-to-one side of the relationship can be modeled using object references.
Consider the department-employee case. In the underlying relational model, the foreign key is in the employee table. The relationship between departments and employees can be modeled using collections in views. The department view can have a collection of employees, and the employee view can have a reference to the department (or inline the department values). This gives both the forward relation (from employee t o department) and the inverse relation (department to list of employees). The department view can also have a collection of references to employee objects instead of embedding the employee objects.
You can update, insert, and delete data in an object view using the same SQL DML you use for object tables. Oracle updates the base tables of the object view if there is no ambiguity.
Views are not always directly updatable.
A view is not directly updatable if the view query contains joins, set operators, aggregate functions, or GROUP BY
or DISTINCT
clauses. Also, individual columns of a view are not directly updatable if they are based on pseudocolumns or expressions in the view query.
If a view is not directly updatable, you can still update it indirectly using INSTEAD OF
triggers. To do so, you define an INSTEAD
OF
trigger for each kind of DML statement you want to execute on the view. In the INSTEAD
OF
trigger, code the operations that must take place on the underlying tables of the view to accomplish the desired change in the view. Then, when you issue a DML statement for which you have defined an INSTEAD
OF
trigger, Oracle transparently runs the associated trigger.
See Also: "Using INSTEAD OF Triggers to Control Mutating and Validation" for an example of anINSTEAD OF trigger |
Note: In an object view hierarchy,UPDATE and DELETE statements operate polymorphically just as SELECT statements do: the set of rows picked out by an UPDATE or DELETE statement on a view implicitly includes qualifying rows in any subviews of the specified view as well. |
For example, the following statement, which deletes all persons from Person_v
, also deletes all students from Student_v
and all employees from the Employee_v
view.
DELETE FROM Person_v;
To exclude subviews and restrict the affected rows to just those in the view specified, use the ONLY
keyword. For example, the following statement updates only persons and not employees or students.
UPDATE ONLY(Person_v) SET address = ...
See Also: "Object View Hierarchies" for a discussion of object view hierarchy and examples definingStudent_v and Employee_v views |
You can modify a nested table by inserting new elements and updating or deleting existing elements. Nested table columns that are virtual or synthesized, as in a view, are not usually updatable. To overcome this, Oracle allows INSTEAD
OF
triggers to be created on these columns.
The INSTEAD
OF
trigger defined on a nested table column (of a view) is fired when the column is modified. Note that if the entire collection is replaced (by an update of the parent row), the INSTEAD
OF
trigger on the nested table column is not fired.
INSTEAD
OF
triggers provide a way to update complex views that otherwise could not be updated. They can also be used to enforce constraints, check privileges, and validate DML statements. Using these triggers, you can control mutation that might be caused by inserting, updating, and deleting in the objects created though an object view.
For instance, to enforce the condition that the number of employees in a department cannot exceed 10, you can write an INSTEAD
OF
trigger for the employee view. The trigger is not needed to execute the DML statement because the view can be updated, but you need it to enforce the constraint.
Example 6-8 shows how to implement the trigger by means of SQL statements.
Example 6-8 Creating INSTEAD OF Triggers on a View
-- Requires Ex. 6-2, Ex. 6-4, and Ex. 6-6 CREATE TRIGGER emp_instr INSTEAD OF INSERT on emp_view FOR EACH ROW DECLARE dept_var dept_t; emp_count integer; BEGIN -- Enforce the constraint -- First get the department number from the reference UTL_REF.SELECT_OBJECT(:NEW.deptref, dept_var); SELECT COUNT(*) INTO emp_count FROM emp WHERE deptno = dept_var.deptno; IF emp_count < 9 THEN -- Do the insert INSERT INTO emp (empno, empname, salary, deptno) VALUES (:NEW.empno, :NEW.ename, :NEW.salary, dept_var.deptno); END IF; END; /
Although you cannot directly access remote tables as object tables, object views let you access remote tables as if they were object tables.
Consider a company with two branches; one in Washington D.C. and another in Chicago. Each site has an employee table. The headquarters in Washington has a department table with a list of all the departments. To get a total view of the entire organization, you can create views over the individual remote tables and then a overall view of the organization.
To this requires the following:
Update the entry in listener.ora
, such as: (ADDRESS=(PROTOCOL=tcp)
(HOST=stadv07.us.example.com)(PORT=1640))
Add entries to tnsnames.ora
, such as: chicago=(DESCRIPTION= (ADDRESS=(PROTOCOL=ipc)(KEY=linux)) (CONNECT_DATA=(SERVICE_NAME=linux.regress.rdbms.dev.us.example.com)))
Provide CREATE
DATABASE
LINK
code as shown in Example 6-9
Example 6-9 begins by creating an object view for each employee table and then creates the global view.
Example 6-9 Creating an Object View to Access Remote Tables
-- Requires Ex. 6-2, Ex. 6-4, and Ex. 6-6 -- Example requires DB links, such as these, modify for your use and uncomment -- CREATE DATABASE LINK chicago CONNECT TO hr IDENTIFIED BY hr USING 'inst1'; -- CREATE DATABASE LINK washington CONNECT TO hr IDENTIFIED BY hr USING 'inst1'; CREATE VIEW emp_washington_view (eno, ename, salary, job) AS SELECT e.empno, e.empname, e.salary, e.job FROM emp@washington e; CREATE VIEW emp_chicago_view (eno, ename, salary, job) AS SELECT e.empno, e.empname, e.salary, e.job FROM emp@chicago e; CREATE VIEW orgnzn_view OF dept_t WITH OBJECT IDENTIFIER (deptno) AS SELECT d.deptno, d.deptname, address_t(d.deptstreet,d.deptcity,d.deptstate,d.deptzip) AS deptaddr, CAST( MULTISET ( SELECT e.eno, e.ename, e.salary, e.job FROM emp_washington_view e) AS employee_list_t) AS emp_list FROM dept d WHERE d.deptcity = 'Washington' UNION ALL SELECT d.deptno, d.deptname, address_t(d.deptstreet,d.deptcity,d.deptstate,d.deptzip) AS deptaddr, CAST( MULTISET ( SELECT e.eno, e.ename, e.salary, e.job FROM emp_chicago_view e) AS employee_list_t) AS emp_list FROM dept d WHERE d.deptcity = 'Chicago';
This view has a list of all employees for each department. The UNION
ALL
clause is used because employees cannot work in more than one department.
You can define circular references in object views using the MAKE_REF
operator: view_A
can refer to view_B
which in turn can refer to view_A
. This allows an object view to synthesize a complex structure such as a graph from relational data.
For example, in the case of the department and employee, the department object currently includes a list of employees. To conserve space, you may want to put references to the employee objects inside the department object, instead of materializing all the employees within the department object. You can construct (pin) the references to employee objects, and later follow the references using the dot notation to extract employee information.
Because the employee object already has a reference to the department in which the employee works, an object view over this model contains circular references between the department view and the employee view.
You can create circular references between object views in two different ways:
Note: Both ways to create circular references require the setup described in "Tables and Types to Demonstrate Circular View References". |
First View After Second View
Create view A without any reference to view B.
Create view B, which includes a reference to view A.
Replace view A with a new definition that includes the reference to view B.
See the example in "Method 1: Re-create First View After Creating Second View"
First View Using the FORCE
Keyword
Create view A with a reference to view B using the FORCE
keyword.
Create view B with a reference to view A. When view A is used, it is validated and re-compiled.
See the example in "Method 2: Create First View Using FORCE Keyword"
Method 2 has fewer steps, but the FORCE
keyword may hide errors in the view creation. You need to query the USER_ERRORS
catalog view to see if there were any errors during the view creation. Use this method only if you are sure that there are no errors in the view creation statement.
Also, if errors prevent the views from being recompiled upon use, you must recompile them manually using the ALTER
VIEW
COMPILE
command.
Perform the setup described next before attempting to use either method of creating circular view references.
First, you need set up some relational tables and associated object types. Although the tables contain some objects, they are not object tables. To access the data objects, you will create object views later.
The emp
table stores the employee information:
Example 6-10 Creating emp table to demonstrate circular references
CREATE TABLE emp ( empno NUMBER PRIMARY KEY, empname VARCHAR2(20), salary NUMBER, deptno NUMBER ); -- first create a dummy, that is, incomplete, department type, so emp_t type -- created later will succeed CREATE TYPE dept_t; / -- Create the employee type with a reference to the department,dept_t
: CREATE TYPE emp_t AS OBJECT ( eno NUMBER, ename VARCHAR2(20), salary NUMBER, deptref REF dept_t ); / -- Represent the list of references to employees as a nested table: CREATE TYPE employee_list_ref_t AS TABLE OF REF emp_t; / -- Create the department table as a relational table CREATE TABLE dept ( deptno NUMBER PRIMARY KEY, deptname VARCHAR2(20), deptstreet VARCHAR2(20), deptcity VARCHAR2(10), deptstate CHAR(2), deptzip VARCHAR2(10) ); -- Create object types that map to columns from the relational tables: CREATE TYPE address_t AS OBJECT ( street VARCHAR2(20), city VARCHAR2(10), state CHAR(2), zip VARCHAR2(10)); / -- Fill in the definition fordept_t
, the incomplete type you previously created: CREATE OR REPLACE TYPE dept_t AS OBJECT ( dno NUMBER, dname VARCHAR2(20), deptaddr address_t, empreflist employee_list_ref_t); /
As Example 6-10 indicates, you must create the emp
table, then create a dummy department type, dept_t
which will enable the emp_t
type to succeed once you create it. After that, create emp_t
with a reference to dept_t
. Create a list of references to employees as a nested table, employee_list_ref_t
and create the department table, dept
. Then create an object type, address_t
that has columns mapping to the relational tables, and finally fill in the definition for the incomplete dept_t
.
The following is example data you could use:
insert into emp values(1,'John','900',100); insert into emp values(2,'james','1000',100); insert into emp values(3,'jack',2000,200);
Now that you have established the underlying relational table definitions, in the previous section, create the object views on top of them.
Method 1: Re-create First View After Creating Second View
First create the employee view with a null in the deptref
column. Later, you can turn that column into a reference.
Next, create the department view, which includes references to the employee objects. This creates a list of references to employee objects, instead of including the entire employee object.
Next, re-create the employee view with the reference to the department view.
Example 6-11 Creating an Object View with a Circular Reference, Method 1
-- Requires Ex. 6-10 CREATE VIEW emp_view OF emp_t WITH OBJECT IDENTIFIER(eno) AS SELECT e.empno, e.empname, e.salary, NULL FROM emp e; -- create department view, including references to the employee objects CREATE VIEW dept_view OF dept_t WITH OBJECT IDENTIFIER(dno) AS SELECT d.deptno, d.deptname, address_t(d.deptstreet,d.deptcity,d.deptstate,d.deptzip), CAST( MULTISET ( SELECT MAKE_REF(emp_view, e.empno) FROM emp e WHERE e.deptno = d.deptno) AS employee_list_ref_t) FROM dept d; CREATE OR REPLACE VIEW emp_view OF emp_t WITH OBJECT IDENTIFIER(eno) AS SELECT e.empno, e.empname, e.salary, MAKE_REF(dept_view, e.deptno) FROM emp e;
This creates the views.
Method 2: Create First View Using FORCE Keyword
If you are sure that the view creation statement has no syntax errors, you can use the FORCE
keyword to force the creation of the first view without the other view being present.
First, create an employee view that includes a reference to the department view, which does not exist at this point. This view cannot be queried until the department view is created properly.
Next, create a department view that includes references to the employee objects. You do not have to use the FORCE
keyword here, because emp_view
already exists. This allows you to query the department view, getting the employee object by dereferencing the employee reference from the nested table empreflist
.
Example 6-12 Creating view with FORCE Method 2
-- Requires Ex. 6-10 -- create employee view CREATE OR REPLACE FORCE VIEW emp_view OF emp_t WITH OBJECT IDENTIFIER(eno) AS SELECT e.empno, e.empname, e.salary, MAKE_REF(dept_view, e.deptno) FROM emp e; -- create a department view that includes references to the employee objects CREATE OR REPLACE VIEW dept_view OF dept_t WITH OBJECT IDENTIFIER(dno) AS SELECT d.deptno, d.deptname, address_t(d.deptstreet,d.deptcity,d.deptstate,d.deptzip), CAST( MULTISET ( SELECT MAKE_REF(emp_view, e.empno) FROM emp e WHERE e.deptno = d.deptno) AS employee_list_ref_t) FROM dept d; -- Querying with DEREF method SELECT DEREF(e.COLUMN_VALUE) FROM TABLE( SELECT e.empreflist FROM dept_view e WHERE e.dno = 100) e;
COLUMN_VALUE
is a special name that represents the scalar value in a scalar nested table. In this case, COLUMN_VALUE
denotes the reference to the employee objects in the nested table empreflist
.
You can also access the employee number only, for all those employees whose name begins with John
.
Example 6-13 Querying with COLUMN_VALUE
-- Requires Ex. 6-10 and 6-12 SELECT e.COLUMN_VALUE.eno FROM TABLE(SELECT e.empreflist FROM dept_view e WHERE e.dno = 100) e WHERE e.COLUMN_VALUE.ename like 'John%';
To get a tabular output, unnest the list of references by joining the department table with the items in its nested table:
Example 6-14 Querying with COLUMN_VALUE, Unnesting References
-- Requires Ex. 6-10 and 6-12SELECT d.dno, e.COLUMN_VALUE.eno, e.COLUMN_VALUE.ename FROM dept_view d, TABLE(d.empreflist) e WHERE e.COLUMN_VALUE.ename like 'John%' AND d.dno = 100;
Finally, you can rewrite the preceding query to use the emp_view
instead of the dept_view
to show how to navigate from one view to the other:
An object view hierarchy is a set of object views each of which is based on a different type in a type hierarchy. Subviews in a view hierarchy are created under a superview, analogously to the way subtypes in a type hierarchy are created under a supertype.
Each object view in a view hierarchy is populated with objects of a single type, but queries on a given view implicitly address its subviews as well. Thus an object view hierarchy gives you a simple way to frame queries that can return a polymorphic set of objects of a given level of specialization or greater.
For example, suppose you have the following type hierarchy, with person_typ
as the root:
If you have created an object view hierarchy based on this type hierarchy, with an object view built on each type, you can query the object view that corresponds to the level of specialization you are interested in. For instance, you can query the view of student_typ
to get a result set that contains only students, including part-time students.
You can base the root view of an object view hierarchy on any type in a type hierarchy: you do not need to start the object view hierarchy at the root type. Nor do you need to extend an object view hierarchy to every leaf of a type hierarchy or cover every branch. However, you cannot skip intervening subtypes in the line of descent. Any subview must be based on a direct subtype of the type of its direct superview.
Just as a type can have multiple sibling subtypes, an object view can have multiple sibling subviews. However, a subview based on a given type can participate in only one object view hierarchy: two different object view hierarchies cannot each have a subview based on the same subtype.
A subview inherits the object identifier (OID) from its superview. An OID cannot be explicitly specified in any subview.
A root view can explicitly specify an object identifier using the WITH OBJECT ID
clause. If the OID is system-generated or the clause is not specified in the root view, then subviews can be created only if the root view is based on a table or view that also uses a system-generated OID.
The query underlying a view determines whether or not the view is updatable. For a view to be updatable, its query must contain no joins, set operators, aggregate functions, GROUP
BY
clause, DISTINCT
clause, pseudocolumns, or expressions. The same applies to subviews.
If a view is not updatable, you can define INSTEAD
OF
triggers to perform appropriate DML actions. Note that INSTEAD
OF
triggers are not inherited by subviews.
All views in a view hierarchy must be in the same schema.
Note: You can create views of types that are non-instantiable. A non-instantiable type cannot have instances, so ordinarily there would be no point in creating an object view of such a type. However, a non-instantiable type can have subtypes that are instantiable. The ability to create object views of non-instantiable types enables you to base an object view hierarchy on a type hierarchy that contains a non-instantiable type. |
You build an object view hierarchy by creating subviews under a root view. You do this by using the UNDER
keyword in the CREATE
VIEW
statement, as show in Example 6-17.
The same object view hierarchy can be based on different underlying storage models. In other words, a variety of layouts or designs of underlying tables can produce the same object view hierarchy. The design of the underlying storage model affects the performance and updatability of the object view hierarchy.
This section describes three possible storage models. In the first, a flat model, all views in the object view hierarchy are based on the same table. In the second, a horizontal model, each view has a one-to-one correspondence with a different table. And in the third, a vertical model, the views are constructed using joins.
To execute any of these storage models, first create types shown in Example 6-16.
Example 6-16 Creating Types for Storage Model Examples
CREATE TYPE person_typ AS OBJECT ( ssn NUMBER, name VARCHAR2(30), address VARCHAR2(100)) NOT FINAL;/ CREATE TYPE student_typ UNDER person_typ ( deptid NUMBER, major VARCHAR2(30)) NOT FINAL;/ CREATE TYPE employee_typ UNDER person_typ ( empid NUMBER, mgr VARCHAR2(30));/
This section contains the following topics:
In the flat model, all the views in the hierarchy are based on the same table. In the following example, the single table AllPersons
contains columns for all the attributes of person_typ
, student_typ
, and employee_typ
.
Figure 6-2 Flat Storage Model for Object View Hierarchy
The typeid
column identifies the type of each row. These possible values are the types created in Example 6-16, 1 = person_typ
, 2 = student_typ, and
3 = employee_typ
:
Example 6-17 creates the table AllPersons
and then the views that make up the object view hierarchy:
Example 6-17 Creating an Object View Hierarchy
-- Requires Ex. 6-16 CREATE TABLE AllPersons ( typeid NUMBER(1), ssn NUMBER, name VARCHAR2(30), address VARCHAR2(100), deptid NUMBER, major VARCHAR2(30), empid NUMBER, mgr VARCHAR2(30)); CREATE VIEW Person_v OF person_typ WITH OBJECT OID(ssn) AS SELECT ssn, name, address FROM AllPersons WHERE typeid = 1; CREATE VIEW Student_v OF student_typ UNDER Person_v AS SELECT ssn, name, address, deptid, major FROM AllPersons WHERE typeid = 2; CREATE VIEW Employee_v OF employee_typ UNDER Person_v AS SELECT ssn, name, address, empid, mgr FROM AllPersons WHERE typeid = 3;
The flat model has the advantage of simplicity and poses no obstacles to supporting indexes and constraints. Its drawbacks are:
A single table cannot contain more than 1000 columns, so the flat model imposes a 1000-column limit on the total number of columns that the object view hierarchy can contain.
Each row of the table will have NULLs for all the attributes not belonging to its type. Such non-trailing NULLs can adversely affect performance.
On the horizontal model, each view or subview is based on a different table. In the example, the tables are relational, but they could just as well be object tables for which column substitutability is turned off.
Figure 6-3 Horizontal Storage Model for Object View Hierarchy
Example 6-18 creates tables and then views based on these tables.
Example 6-18 -- Creating Table Horizontal Model
-- Requires Ex. 6-16 and Ex. 6-17 CREATE TABLE only_persons ( ssn NUMBER, name VARCHAR2(30), address VARCHAR2(100)); CREATE TABLE only_students ( ssn NUMBER, name VARCHAR2(30), address VARCHAR2(100), deptid NUMBER, major VARCHAR2(30)); CREATE TABLE only_employees ( ssn NUMBER, name VARCHAR2(30), address VARCHAR2(100), empid NUMBER, mgr VARCHAR2(30)); CREATE OR REPLACE VIEW Person_v OF person_typ WITH OBJECT OID(ssn) AS SELECT * FROM only_persons; CREATE OR REPLACE VIEW Student_v OF student_typ UNDER Person_v AS SELECT * FROM only_students; CREATE OR REPlACE VIEW Employee_v OF employee_typ UNDER Person_v AS SELECT * FROM only_employees;
The horizontal model is very efficient at processing queries of the form:
Example 6-19 -- Querying views horizontal model
-- Requires Ex. 6-16 and Ex. 6-17 -- add the following data insert into only_persons values(1234,'John','abc'); insert into only_students values(1111,'James','abc',100,'CS'); insert into only_employees values(2222,'jack','abc',400,'Juliet'); SELECT VALUE(p) F%rROM Person_v p WHERE VALUE(p) IS OF (ONLY student_typ); OUTPUT: VALUE(P)(SSN, NAME, ADDRESS) -------------------------------------------------------------------------------- STUDENT_TYP(1111, 'James', 'abc', 100, 'CS')
Such queries only need to access a single physical table to get all the objects of the specific type. The drawbacks of this model are that queries such as SELECT * FROM
view
require performing a UNION
over all the underlying tables and projecting the rows over just the columns in the specified view. (See "Querying a View in a Hierarchy".) Also, indexes on attributes (and unique constraints) must span multiple tables, and support for this does not currently exist.
In the vertical model, there is a physical table corresponding to each view in the hierarchy, but the physical tables store only those attributes that are unique to their corresponding subtypes.
Figure 6-4 Vertical Storage Model for Object View Hierarchy
Example 6-20 creates tables and then corresponding views.
Example 6-20 Creating table, views vertical model
CREATE TABLE all_personattrs ( typeid NUMBER, ssn NUMBER, name VARCHAR2(30), address VARCHAR2(100)); CREATE TABLE all_studentattrs ( ssn NUMBER, deptid NUMBER, major VARCHAR2(30)); CREATE TABLE all_employeeattrs ( ssn NUMBER, empid NUMBER, mgr VARCHAR2(30)); CREATE OR REPLACE VIEW Person_v OF person_typ WITH OBJECT OID(ssn) AS SELECT ssn, name, address FROM all_personattrs WHERE typeid = 1; CREATE OR REPLACE VIEW Student_v OF student_typ UNDER Person_v AS SELECT x.ssn, x.name, x.address, y.deptid, y.major FROM all_personattrs x, all_studentattrs y WHERE x.typeid = 2 AND x.ssn = y.ssn; CREATE OR REPLACE VIEW Employee_v OF employee_typ UNDER Person_v AS SELECT x.ssn, x.name, x.address, y.empid, y.mgr FROM all_personattrs x, all_employeeattrs y WHERE x.typeid = 3 AND x.ssn = y.ssn;
The vertical model can efficiently process queries of the kind SELECT * FROM
root_view
, and it is possible to index individual attributes and impose unique constraints on them. However, to re-create an instance of a type, a join over object identifiers (OIDs) must be performed for each level that the type is removed from the root in the hierarchy.
You can query any view or subview in an object view hierarchy; rows are returned for the declared type of the view that you query and for any of the subtypes of that type. So, for instance, in an object view hierarchy based on the person_typ
type hierarchy, you can query the view of person_typ
to get a result set that contains all persons, including students and employees; or you can query the view of student_typ
to get a result set that contains only students, including part-time students.
In the SELECT
list of a query, you can include either functions such as REF()
and VALUE()
that return an object instance, or you can specify object attributes of the declared type of the view, such as the name
and ssn
attributes of person_typ
.
If you specify functions, to return object instances, the query returns a polymorphic result set: that is, it returns instances of both the declared type of the view and any subtypes of that type.
For example, the following query returns instances of persons, employees, and students of all types, as well as REF
s to those instances.
Example 6-21 Query with REF and Value
-- Requires Ex. 6-20 insert into all_personattrs values(1,1111,'John','abc'); insert into all_personattrs values(2,2222,'Jack','def'); insert into all_personattrs values(3,3333,'James','ghi'); insert into all_studentattrs values(2222,100,'CS'); insert into all_employeeattrs values(3333,444,'Julia'); SELECT REF(p), VALUE(p) FROM Person_v p; OUTPUT: REF(P) -------------------------------------------------------------------------------- VALUE(P)(SSN, NAME, ADDRESS) -------------------------------------------------------------------------------- 00004A038A00465A6E6E779EC1F25FE040578CE70A447E0000001426010001000100290000000000 090600812A00078401FE0000000B03C20C0C00000000000000000000000000000000000000 PERSON_TYP(1111, 'John', 'abc') 00004A038A00465A6E6E779EC1F25FE040578CE70A447E0000001426010001000100290000000000 090600812A00078401FE0000000B03C2222200000000000000000000000000000000000000 EMPLOYEE_TYP(3333, 'James', 'ghi', 444, 'Julia') 00004A038A00465A6E6E779EC1F25FE040578CE70A447E0000001426010001000100290000000000 REF(P) -------------------------------------------------------------------------------- VALUE(P)(SSN, NAME, ADDRESS) -------------------------------------------------------------------------------- 090600812A00078401FE0000000B03C2171700000000000000000000000000000000000000 STUDENT_TYP(2222, 'Jack', 'def', 100, 'CS')
If you specify individual attributes of the declared type of the view in the SELECT
list or do a SELECT
*
, again the query returns rows for the declared type of the view and any subtypes of that type, but these rows are projected over columns for the attributes of the declared type of the view, and only those columns are used. In other words, the subtypes are represented only with respect to the attributes they inherit from and share with the declared type of the view.
For example, the following query returns rows for all persons and rows for employees and students of all types, but the result uses only the columns for the attributes of person_typ
—namely, name
, ssn
, and address
. It does not show rows for attributes added in the subtypes, such as the deptid
attribute of student_typ
.
SELECT * FROM Person_v;
To exclude subviews from the result, use the ONLY
keyword. The ONLY
keyword confines the selection to the declared type of the view that you are querying:
SELECT VALUE(p) FROM ONLY(Person_v) p;
Generally, a query on a view with subviews requires only the SELECT
privilege on the view being referenced and does not require any explicit privileges on subviews. For example, the following query requires only SELECT
privileges on Person_v
but not on any of its subviews.
SELECT * FROM Person_v;
However, a query that selects for any attributes added in subtypes but not used by the root type requires the SELECT
privilege on all subviews as well. Such subtype attributes may hold sensitive information that should reasonably require additional privileges to access.
The following query, for example, requires SELECT
privileges on Person_v
and also on Student_v
, Employee_v
(and on any other subview of Person_v
) because the query selects object instances and thus gets all the attributes of the subtypes.
SELECT VALUE(p) FROM Person_v p;
To simplify the process of granting SELECT
privileges on an entire view hierarchy, you can use the HIERARCHY
option. Specifying the HIERARCHY
option when granting a user SELECT
privileges on a view implicitly grants SELECT
privileges on all current and future subviews of the view as well. For example:
GRANT SELECT ON Person_v TO user WITH HIERARCHY OPTION;
A query that excludes rows belonging to subviews also requires SELECT
privileges on all subviews. The reason is that information about which rows belong exclusively to the most specific type of an instance may be sensitive, so the system requires SELECT
privileges on subviews for queries (such as the following one) that exclude all rows from subviews.
SELECT * FROM ONLY(Person_v);
This section describes the new object-relational features of Oracle 11g release 1 (11.1). New features information from previous releases is also retained to help users upgrading to the current release.
The following sections describe the new features in Oracle Object-Relational Features:
Oracle Database 11g Release 2 (11.2) New Features in Object-Relational Features
Oracle Database 11g Release 1 (11.1) New Features in Object-Relational Features
Oracle Database 10g Release 1 (10.1) New Features in Object-Relational Features
FORCE Option Added to CREATE OR REPLACE TYPE Statement
CREATE
OR
REPLACE
TYPE
statements now have a FORCE
option, which enables you to replace the type even if it has type dependents. This does not work without the FORCE
option.
Support for Generalized Invocation
Generalized invocation syntax is now supported. Therefore, a member method in a subtype can statically invoke (dispatch) a member method in any supertype in the supertype hierarchy of the current subtype, including the subtype's immediate supertype. See "Generalized Invocation".
New object-relational features for Oracle 10g release 1 (10.1) include the following collection enhancements:
New functionality for nested table and varray storage, including the evolution of varray size and specification of a tablespace when storing nested tables. See "Collection Data Types".
New functionality for nested table comparisons and ANSI SQL multiset operations for nested tables. See "Operations on Collection Data Types".
Object-Relational Developer's Guide
11g Release 2 (11.2)
E11822-04
August 2011
Oracle Database Object-Relational Developer's Guide 11g Release 2 (11.2)
E11822-04
Copyright © 1996, 2011, Oracle and/or its affiliates. All rights reserved.
Contributors: Sundeep Abraham, Shashaanka Agrawal, Geeta Arora, Eric Belden, Janis Greenberg, Chandrasekharan Iyer, Geoff Lee, Anand Manikutty, Valarie Moore, Magdi Morsi, Helen Yeh, Adiel Yoaz, Qin Yu
This software and related documentation are provided under a license agreement containing restrictions on use and disclosure and are protected by intellectual property laws. Except as expressly permitted in your license agreement or allowed by law, you may not use, copy, reproduce, translate, broadcast, modify, license, transmit, distribute, exhibit, perform, publish, or display any part, in any form, or by any means. Reverse engineering, disassembly, or decompilation of this software, unless required by law for interoperability, is prohibited.
The information contained herein is subject to change without notice and is not warranted to be error-free. If you find any errors, please report them to us in writing.
If this is software or related documentation that is delivered to the U.S. Government or anyone licensing it on behalf of the U.S. Government, the following notice is applicable:
U.S. GOVERNMENT RIGHTS Programs, software, databases, and related documentation and technical data delivered to U.S. Government customers are "commercial computer software" or "commercial technical data" pursuant to the applicable Federal Acquisition Regulation and agency-specific supplemental regulations. As such, the use, duplication, disclosure, modification, and adaptation shall be subject to the restrictions and license terms set forth in the applicable Government contract, and, to the extent applicable by the terms of the Government contract, the additional rights set forth in FAR 52.227-19, Commercial Computer Software License (December 2007). Oracle America, Inc., 500 Oracle Parkway, Redwood City, CA 94065.
This software or hardware is developed for general use in a variety of information management applications. It is not developed or intended for use in any inherently dangerous applications, including applications that may create a risk of personal injury. If you use this software or hardware in dangerous applications, then you shall be responsible to take all appropriate fail-safe, backup, redundancy, and other measures to ensure its safe use. Oracle Corporation and its affiliates disclaim any liability for any damages caused by use of this software or hardware in dangerous applications.
Oracle and Java are registered trademarks of Oracle and/or its affiliates. Other names may be trademarks of their respective owners.
Intel and Intel Xeon are trademarks or registered trademarks of Intel Corporation. All SPARC trademarks are used under license and are trademarks or registered trademarks of SPARC International, Inc. AMD, Opteron, the AMD logo, and the AMD Opteron logo are trademarks or registered trademarks of Advanced Micro Devices. UNIX is a registered trademark of The Open Group.
This software or hardware and documentation may provide access to or information on content, products, and services from third parties. Oracle Corporation and its affiliates are not responsible for and expressly disclaim all warranties of any kind with respect to third-party content, products, and services. Oracle Corporation and its affiliates will not be responsible for any loss, costs, or damages incurred due to your access to or use of third-party content, products, or services.
This chapter explains how to create and manage these collection types: varrays and nested tables.
This chapter contains these topics:
Oracle supports the varray and nested table collection data types.
A varray is an ordered collection of elements.
A nested table can have any number of elements and is unordered.
If you need to store only a fixed number of items, or loop through the elements in order, or often need to retrieve and manipulate the entire collection as a value, then use a varray.
If you need to run efficient queries on a collection, handle arbitrary numbers of elements, or perform mass insert, update, or delete operations, then use a nested table. See "Design Considerations for Collections".
This section includes the following topics:
This section shows the creation of a nested table type. Creation of a VARRAY
type is demonstrated in "Varrays".
Example 5-1 demonstrates creating a person_typ
object and a people_typ
as a nested table type of person_typ
objects, which are both used in subsequent examples in this chapter.
Example 5-1 CREATE TYPE person_typ for Subsequent Examples
CREATE TYPE person_typ AS OBJECT ( idno NUMBER, name VARCHAR2(30), phone VARCHAR2(20), MAP MEMBER FUNCTION get_idno RETURN NUMBER, MEMBER PROCEDURE display_details ( SELF IN OUT NOCOPY person_typ ) ); / CREATE TYPE BODY person_typ AS MAP MEMBER FUNCTION get_idno RETURN NUMBER IS BEGIN RETURN idno; END; MEMBER PROCEDURE display_details ( SELF IN OUT NOCOPY person_typ ) IS BEGIN -- use the put_line procedure of the DBMS_OUTPUT package to display details DBMS_OUTPUT.put_line(TO_CHAR(idno) || ' - ' || name || ' - ' || phone); END; END; / CREATE TYPE people_typ AS TABLE OF person_typ; -- nested table type /
You create an instance of a collection type in the same way that you create an instance of any other object type, namely, by calling the constructor method of the type. The name of a constructor method is simply the name of the type. You specify the elements of the collection as a comma-delimited list of arguments to the method, for example.
( person_typ(1, 'John Smith', '1-650-555-0135'),
Calling a constructor method with an empty list creates an empty collection of that type. Note that an empty collection is an actual collection that happens to be empty; it is not the same as a null collection. See "Design Considerations for Nested Tables" for more information on using nested tables.
You can use a constructor method in a SQL statement to insert values into a nested table.
Example 5-2 first creates a table that contains an instance of the nested table type people_typ
, named people_column
, and then shows how to use the constructor method in a SQL statement to insert values into people_typ
. This example uses a literal invocation of the constructor method.
Example 5-2 Using the Constructor Method to Insert Values into a Nested Table
-- Requires Ex. 5-1 CREATE TABLE people_tab ( group_no NUMBER, people_column people_typ ) -- an instance of nested table NESTED TABLE people_column STORE AS people_column_nt; -- storage table for NT INSERT INTO people_tab VALUES ( 100, people_typ( person_typ(1, 'John Smith', '1-650-555-0135'), person_typ(2, 'Diane Smith', NULL)));
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.
Example 5-3 shows how to use literal invocations of constructor methods to specify defaults for the person_typ
object and the people_typ
nested table:
Example 5-3 Creating the department_persons Table Using the DEFAULT Clause
-- requires Ex. 5-1 CREATE TABLE department_persons ( dept_no NUMBER PRIMARY KEY, dept_name CHAR(20), dept_mgr person_typ DEFAULT person_typ(10,'John Doe',NULL), dept_emps people_typ DEFAULT people_typ() ) -- instance of nested table type NESTED TABLE dept_emps STORE AS dept_emps_tab; INSERT INTO department_persons VALUES ( 101, 'Physical Sciences', person_typ(65,'Vrinda Mills', '1-650-555-0125'), people_typ( person_typ(1, 'John Smith', '1-650-555-0135'), person_typ(2, 'Diane Smith', NULL) ) ); INSERT INTO department_persons VALUES ( 104, 'Life Sciences', person_typ(70,'James Hall', '1-415-555-0101'), people_typ() ); -- an empty people_typ table
Note that people_typ()
is a literal invocation of the constructor method for an empty people_typ
nested table.
The department_persons
table can be queried in two ways as shown in Example 5-16 and Example 5-17.
A varray is an ordered set of data elements. All elements of a given varray are of the same data type or a subtype of the declared one. Each element has an index, which is a number corresponding to the position of the element in the array. The index number is used to access a specific element.
When you define a varray, you specify the maximum number of elements it can contain, although you can change this number later. The number of elements in an array is the size of the array.
The following statement creates an array type email_list_arr
that has no more than ten elements, each of data type VARCHAR2(80)
.
CREATE TYPE email_list_arr AS VARRAY(10) OF VARCHAR2(80); /
Example 5-4 creates a VARRAY
type that is an array of an object type. The phone_varray_typ
VARRAY
type is used as a data type for a column in the dept_phone_list
table. The INSERT
statements show how to insert values into phone_varray_typ
by invoking the constructors for the varray phone_varray_typ
and the object phone_typ
.
Example 5-4 Creating and Populating a VARRAY Data Type
CREATE TYPE phone_typ AS OBJECT ( country_code VARCHAR2(2), area_code VARCHAR2(3), ph_number VARCHAR2(7)); / CREATE TYPE phone_varray_typ AS VARRAY(5) OF phone_typ; / CREATE TABLE dept_phone_list ( dept_no NUMBER(5), phone_list phone_varray_typ); INSERT INTO dept_phone_list VALUES ( 100, phone_varray_typ( phone_typ ('01', '650', '5550123'), phone_typ ('01', '650', '5550148'), phone_typ ('01', '650', '5550192')));
Creating an array type, as with a SQL object type, does not allocate space. It defines a data type, which you can use as:
The data type of a column of a relational table.
An object type attribute.
The type of a PL/SQL variable, parameter, or function return value.
A varray is normally stored inline, that is, in the same tablespace as the other data in its row. If it is sufficiently large, Oracle stores it as a BLOB
. See "Storage Considerations for Varrays".
You can create a VARRAY
type of XMLType
or LOB
type for procedural purposes, such as in PL/SQL or view queries. However, database storage for varrays of these types is not supported. Thus you cannot create an object table or an object type column of a varray type of XMLType
or LOB
type.
See Also: Oracle Database SQL Language Reference for information and examples on theSTORE AS LOB clause of the CREATE TABLE statement |
A nested table is an unordered set of data elements, all of the same data type. No maximum is specified in the definition of the table, and the order of the elements is not preserved. You select, insert, delete, and update in a nested table just as you do with ordinary tables using the TABLE
expression.
A nested table can be viewed as a single column. If the column in a nested table is an object type, the table can also be viewed as a multi-column table, with a column for each attribute of the object type.
To declare nested table types, use the CREATE
TYPE
... AS
TABLE
OF
statement. For example:
CREATE TYPE people_typ AS TABLE OF person_typ;
A table type definition does not allocate space. It defines a type, which you can use as:
The data type of a column of a relational table.
An object type attribute.
A PL/SQL variable, parameter, or function return type.
Elements of a nested table are actually stored in a separate storage table.
Oracle stores nested table data in a single storage table associated with the object table for both nested table types that are columns in a relational table or attributes in an object table. The storage table contains a column that identifies the parent table row or object that each element of the nested table belongs to. See Figure 9-2, "Nested Table Storage".
The NESTED
TABLE..STORE AS
clause specifies storage names for nested tables. Storage names are used to create an index on a nested table.
Example 5-5 demonstrates creating and populating a nested table, and specifying the nested table storage using the person_typ
object and the people_typ
nested table as defined in Example 5-1.
Example 5-5 Creating and Populating Simple Nested Tables
-- Requires 5-1 CREATE TABLE students ( graduation DATE, math_majors people_typ, -- nested tables (empty) chem_majors people_typ, physics_majors people_typ) NESTED TABLE math_majors STORE AS math_majors_nt -- storage tables NESTED TABLE chem_majors STORE AS chem_majors_nt NESTED TABLE physics_majors STORE AS physics_majors_nt; CREATE INDEX math_idno_idx ON math_majors_nt(idno); CREATE INDEX chem_idno_idx ON chem_majors_nt(idno); CREATE INDEX physics_idno_idx ON physics_majors_nt(idno); INSERT INTO students (graduation) VALUES ('01-JUN-03'); UPDATE students SET math_majors = people_typ (person_typ(12, 'Bob Jones', '650-555-0130'), person_typ(31, 'Sarah Chen', '415-555-0120'), person_typ(45, 'Chris Woods', '415-555-0124')), chem_majors = people_typ (person_typ(51, 'Joe Lane', '650-555-0140'), person_typ(31, 'Sarah Chen', '415-555-0120'), person_typ(52, 'Kim Patel', '650-555-0135')), physics_majors = people_typ (person_typ(12, 'Bob Jones', '650-555-0130'), person_typ(45, 'Chris Woods', '415-555-0124')) WHERE graduation = '01-JUN-03'; SELECT m.idno math_id, c.idno chem_id, p.idno physics_id FROM students s, TABLE(s.math_majors) m, TABLE(s.chem_majors) c, TABLE(s.physics_majors) p;
A convenient way to access the elements of a nested table individually is to use a nested cursor or the TABLE
function. See "Querying Collections".
A nested table can be stored in a different tablespace than its parent table. In Example 5-6, the nested table is stored in the system
tablespace:
Example 5-6 Specifying a Different Tablespace for Storing a Nested Table
-- Requires Ex. 5-1, must remove code in Ex. 5-2 if created
CREATE TABLE people_tab (
people_column people_typ )
NESTED TABLE people_column STORE AS people_column_nt (TABLESPACE system);
If the TABLESPACE
clause is not specified, then the storage table of the nested table is created in the tablespace where the parent table is created. For multilevel nested tables, Oracle creates the child table in the same tablespace as its immediately preceding parent table.
You can issue an ALTER
TABLE..
MOVE
statement to move a table to a different tablespace. If you do this on a table with nested table columns, only the parent table moves; no action is taken on the storage tables of the nested table. To move a storage table for a nested table to a different tablespace, issue ALTER
TABLE..
MOVE
on the storage table. For example:
ALTER TABLE people_tab MOVE TABLESPACE system; -- moving table ALTER TABLE people_column_nt MOVE TABLESPACE example; -- moving storage table
Now the people_tab
table is in the system
tablespace and the nested table storage is stored in the example
tablespace.
When the element type of a VARRAY
type or nested table type is a variable character, or a RAW
or numeric type, you can increase the size of the variable character or RAW
type, or increase the precision of the numeric type. A new type version is generated for the VARRAY
type or nested table type.
You make these changes using an ALTER
TYPE..MODIFY
statement, which has these options:
INVALIDATE
: Invalidates all dependent objects
CASCADE
: Propagates the change to its type and table dependents
See Also: "ALTER TYPE Statement for Type Evolution" for further description ofINVALIDATE and CASCADE |
Example 5-7 increases the sizes of a VARRAY
and a nested table element type.
Example 5-7 Increasing the Size of an Element Type in a VARRAY and Nested Table
CREATE TYPE email_list_arr AS VARRAY(10) OF VARCHAR2(80); / ALTER TYPE email_list_arr MODIFY ELEMENT TYPE VARCHAR2(100) CASCADE; CREATE TYPE email_list_tab AS TABLE OF VARCHAR2(30); / ALTER TYPE email_list_tab MODIFY ELEMENT TYPE VARCHAR2(40) CASCADE;
The ALTER
TYPE
... MODIFY
LIMIT
syntax allows you to increase the number of elements of a VARRAY
type. If the number is increased, a new type version is generated for the VARRAY
type, and becomes part of the type change history.
The ALTER
TYPE
... MODIFY
LIMIT
statement has these options:
INVALIDATE
: Invalidates all dependent objects
CASCADE
: Propagates the change to its type and table dependents
Example 5-8 Increasing the VARRAY Limit Size
-- if you have already creating following types, drop them. DROP TYPE email_list_tab FORCE; DROP TYPE email_list_arr FORCE; CREATE TYPE email_list_arr AS VARRAY(10) OF VARCHAR2(80); / CREATE TYPE email_list_typ AS OBJECT ( section_no NUMBER, emails email_list_arr); / CREATE TYPE email_varray_typ AS VARRAY(5) OF email_list_typ; / ALTER TYPE email_varray_typ MODIFY LIMIT 100 INVALIDATE;
When a VARRAY
type is altered, changes are propagated to the dependent tables. See "Propagating VARRAY Size Change".
To create a varray of LOB references, first define a VARRAY
type of type REF
email_list_typ
. Note: email_list_typ
was defined in Example 5-8. Next, create a table dept_email_list
and define a column email_addrs
of the array type in it.
Multilevel collection types are collection types whose elements are themselves directly or indirectly another collection type. Possible multilevel collection types are:
Nested table of nested table type
Nested table of varray type
Varray of nested table type
Varray of varray type
Nested table or varray of a user-defined type that has an attribute that is a nested table or varray type
Like single-level collection types, multilevel collection types:
Can be used as columns in a relational table or with object attributes in an object table.
Require that both the source and the target be of the same declared data type for assignment.
This section contains the following topics:
A nested table type column or object table attribute requires a storage table to store rows for all its nested tables as described in "Storing Elements of Nested Tables". With a multilevel nested table collection of nested tables, you must specify nested-table storage clauses for both the inner set and the outer set of nested tables.
Example 5-10 creates the multilevel collection type nt_country_typ
, a nested table of nested tables. The example models a system of corporate regions in which each region has a nested table collection of the countries, and each country has a nested table collection of its locations. This example requires the regions
, countries
, and locations
tables of the Oracle HR
sample schema.
In Example 5-10, the SQL statements create the table region_tab
, which contains the column countries
, whose type is a multilevel collection, nt_country_typ
. This multilevel collection is a nested table of an object type that has the nested table attribute locations
. Separate nested table clauses are provided for the outer countries
nested table and for the inner locations
nested table.
Example 5-10 Multilevel Nested Table Storage
-- Requires the HR sample schema CREATE TYPE location_typ AS OBJECT ( location_id NUMBER(4), street_address VARCHAR2(40), postal_code VARCHAR2(12), city VARCHAR2(30), state_province VARCHAR2(25)); / CREATE TYPE nt_location_typ AS TABLE OF location_typ; -- nested table type / CREATE TYPE country_typ AS OBJECT ( country_id CHAR(2), country_name VARCHAR2(40), locations nt_location_typ); -- inner nested table / CREATE TYPE nt_country_typ AS TABLE OF country_typ; -- multilevel collection type / CREATE TABLE region_tab ( region_id NUMBER, region_name VARCHAR2(25), countries nt_country_typ) -- outer nested table NESTED TABLE countries STORE AS nt_countries_tab (NESTED TABLE locations STORE AS nt_locations_tab);
In Example 5-10 you can refer to the inner nested table locations
by name because this nested table is a named attribute of an object. However, if the inner nested table is not an attribute of an object, it has no name. The keyword COLUMN_VALUE
is provided for this case.
Example 5-11 shows keyword COLUMN_VALUE
used in place of a name for an inner nested table.
Example 5-11 Multilevel Nested Table Storage Using the COLUMN_VALUE Keyword
CREATE TYPE inner_table AS TABLE OF NUMBER; / CREATE TYPE outer_table AS TABLE OF inner_table; / CREATE TABLE tab1 ( col1 NUMBER, -- inner nested table, unnamed col2 outer_table) NESTED TABLE col2 STORE AS col2_ntab (NESTED TABLE COLUMN_VALUE STORE AS cv_ntab);
Example 5-12 shows how to specify physical attributes for the storage tables in the nested table clause.
Example 5-12 Specifying Physical Attributes for Nested Table Storage
-- Requires Ex. 5-10 -- drop the following if you have previously created it DROP TABLE region_tab FORCE; CREATE TABLE region_tab ( region_id NUMBER, region_name VARCHAR2(25), countries nt_country_typ) NESTED TABLE countries STORE AS nt_countries_tab ( (PRIMARY KEY (NESTED_TABLE_ID, country_id)) ORGANIZATION INDEX COMPRESS NESTED TABLE locations STORE AS nt_locations_tab);
Every nested table storage table contains a column, referenceable by NESTED_TABLE_ID
, that keys rows in the storage table to the associated row in the parent table. A parent table that is itself a nested table has two system-supplied ID columns:
A system-supplied ID column that is referenceable by NESTED_TABLE_ID
, which keys its rows back to rows in its parent table.
A system-supplied ID column that is hidden and referenced by the NESTED_TABLE_ID
column in its nested table children.
In Example 5-12, nested table countries
is made an index-organized table (IOT) by adding the ORGANIZATION
INDEX
clause and assigning the nested table a primary key in wh ich the first column is NESTED_TABLE_ID
. This column contains the ID of the row in the parent table with which a storage table row is associated. Specifying a primary key with NESTED_TABLE_ID
as the first column and index-organizing the table causes Oracle database to physically cluster all the nested table rows that belong to the same parent row, for more efficient access.
If you do not specify a primary key with a NESTED_TABLE_ID
column, then the database automatically creates a b-tree index on the NESTED_TABLE_ID
column for better performance.
Each nested table needs its own table storage clause, so you must have as many nested table storage clauses as you have levels of nested tables in a collection. See "Nested Table Storage".
Multilevel varrays are stored in one of two ways, depending on whether the varray is a varray of varrays or a varray of nested tables.
In a varray of varrays, the entire varray is stored inline in the row unless it is larger than approximately 4000 bytes or LOB
storage is explicitly specified.
In a varray of nested tables, the entire varray is stored in a LOB, with only the LOB locator stored in the row. There is no storage table associated with nested table elements of a varray.
You can explicitly specify LOB storage for varrays. The following example does this for a nested table of varray elements.
Example 5-13 shows explicit LOB
storage specified for a varray of varray type.
Example 5-13 Specifying LOB Storage for a VARRAY of VARRAY Type
-- Requires Ex. 5-8, drop following if created DROP TYPE email_varray_typ FORCE; CREATE TYPE email_list_typ2 AS OBJECT ( section_no NUMBER, emails email_list_arr); / CREATE TYPE email_varray_typ AS VARRAY(5) OF email_list_typ2; / CREATE TABLE dept_email_list2 ( dept_no NUMBER, email_addrs email_varray_typ) VARRAY email_addrs STORE AS LOB dept_emails_lob2;
See "Storage Considerations for Varrays". See also Oracle Database SecureFiles and Large Objects Developer's Guide.
Example 5-14 Specifying LOB Storage for a Nested Table of VARRAYs
-- drop the following types if you have created them
DROP TYPE email_list_typ FORCE;
DROP TABLE dept_email_list FORCE;
DROP TYPE email_list_arr FORCE;
CREATE TYPE email_list_arr AS VARRAY(10) OF VARCHAR2(80);
/
CREATE TYPE email_list_typ AS TABLE OF email_list_arr;
/
CREATE TABLE dept_email_list (
dept_no NUMBER,
email_addrs email_list_typ)
NESTED TABLE email_addrs STORE AS email_addrs_nt
(
VARRAY COLUMN_VALUE STORE AS LOB
dept_emails_lob);
Example 5-14 shows the COLUMN_VALUE
keyword used with varrays. See Example 5-11 for discussion of this keyword and its use with nested tables.
Multilevel collection types are created by calling the constructor of the respective type, just like single-level collections and other object types. The constructor for a multilevel collection type is a system-defined function that has the same name as the type and returns a new instance of it. Constructor parameters have the names and types of the attributes of the object type.
Example 5-15 shows the constructor call for the multilevel collection type nt_country_typ
. The nt_country_typ
constructor calls the country_typ
constructor, which calls the nt_location_typ
, which calls the location_typ
constructor.
Note: nt_country_typ is a multilevel collection because it is a nested table that contains another nested table as an attribute. |
Example 5-15 Using Constructors for Multilevel Collections
-- Requires 5-10 and HR sample schema INSERT INTO region_tab VALUES(1, 'Europe', nt_country_typ( country_typ( 'IT', 'Italy', nt_location_typ ( location_typ(1000, '1297 Via Cola di Rie','00989','Roma', ''), location_typ(1100, '93091 Calle della Testa','10934','Venice','') ) ), country_typ( 'CH', 'Switzerland', nt_location_typ ( location_typ(2900, '20 Rue des Corps-Saints', '1730', 'Geneva', 'Geneve'), location_typ(3000, 'Murtenstrasse 921', '3095', 'Bern', 'BE') ) ), country_typ( 'UK', 'United Kingdom', nt_location_typ ( location_typ(2400, '8204 Arthur St', '', 'London', 'London'), location_typ(2500, 'Magdalen Centre, The Oxford Science Park', 'OX9 9ZB', 'Oxford', 'Oxford'), location_typ(2600, '9702 Chester Road', '09629850293', 'Stretford', 'Manchester') ) ) ) );
This section describes the operations on collection data types.
This section contains the following topics:
There are two general ways to query a table that contains a collection type as a column or attribute.
Nest the collections in the result rows that contain them.
Distribute or unnest collections so that each collection element appears on a row by itself.
The following queries use the department_persons
table shown in Example 5-3. The column dept_emps
is a nested table collection of person_typ
type. The dept_emps
collection column appears in the SELECT
list like an ordinary scalar column. Querying a collection column in the SELECT
list this way nests the elements of the collection in the result row that the collection is associated with.
Example 5-16 shows the query retrieving the nested collection of employees.
Example 5-16 Nesting Results of Collection Queries
-- Requires Ex. 5-1 and Ex. 5-3 SELECT d.dept_emps FROM department_persons d;
DEPT_EMPS(IDNO, NAME, PHONE)
-------------------------------------------------------------
PEOPLE_TYP(PERSON_TYP(1, 'John Smith', '1-650-555-0135'),
PERSON_TYP(2, 'Diane Smith', '1-650-555-0135'))
The results are also nested if an object type column in the SELECT
list contains a collection attribute, even if that collection is not explicitly listed in the SELECT
list itself. For example, the query SELECT
*
FROM
department_persons
produces a nested result.
Not all tools or applications can deal with results in a nested format. To view Oracle collection data using tools that require a conventional format, you must unnest, or flatten, the collection attribute of a row into one or more relational rows. You can do this using a TABLE
expression with the collection. TABLE
expressions enable you to query a collection in the FROM
clause like a table. In effect, you join the nested table with the row that contains the nested table.
TABLE
expressions can be used to query any collection value expression, including transient values such as variables and parameters.
See Also: Oracle Database SQL Language Reference for further information on theTABLE expression and unnesting collections |
The query in Example 5-17, like that of Example 5-16, retrieves the collection of employees, but here the collection is unnested.
Example 5-17 Unnesting Results of Collection Queries
-- Requires Ex. 5-1 and 5-3 SELECT e.* FROM department_persons d, TABLE(d.dept_emps) e;
IDNO NAME PHONE
---------- ------------------------------ ---------------
1 John Smith 1-650-555-0135
2 Diane Smith 1-650-555-0135
Example 5-17 shows that a TABLE
expression can have its own table alias. A table alias for the TABLE
expression appears in the SELECT
list to select columns returned by the TABLE
expression.
The TABLE
expression uses another table alias to specify the table that contains the collection column that the TABLE
expression references. The expression TABLE(d.dept_emps)
specifies the department_persons
table as containing the dept_emps
collection column. To reference a table column, a TABLE
expression can use the table alias of any table appearing to the left of it in a FROM
clause. This is called left correlation.
In the example, the department_persons
table is listed in the FROM
clause solely to provide a table alias for the TABLE
expression to use. No columns from the department_persons
table other than the column referenced by the TABLE
expression appear in the result.
The following example produces rows only for departments that have employees.
SELECT d.dept_no, e.* FROM department_persons d, TABLE(d.dept_emps) e;
To get rows for departments with or without employees, you can use outer-join syntax:
SELECT d.dept_no, e.* FROM department_persons d, TABLE(d.dept_emps) (+) e;
The (+) indicates that the dependent join between department_persons
and e.dept_emps
should be NULL
-augmented. That is, there will be rows of department_persons
in the output for which e.dept_emps
is NULL
or empty, with NULL
values for columns corresponding to e.dept_emps
.
The examples in "Unnesting Results of Collection Queries" show a TABLE
expression that contains the name of a collection. Alternatively, a TABLE
expression can contain a subquery of a collection.
Example 5-18 returns the collection of employees whose department number is 101
.
Example 5-18 Using a Table Expression Containing a Subquery of a Collection
-- Requires Ex. 5-1 and 5-3 SELECT * FROM TABLE(SELECT d.dept_emps FROM department_persons d WHERE d.dept_no = 101);
Subqueries in a TABLE
expression have these restrictions:
The subquery must return a collection type.
The SELECT
list of the subquery must contain exactly one item.
The subquery must return only a single collection; it cannot return collections for multiple rows. For example, the subquery SELECT
dept_emps
FROM
department_persons
succeeds in a TABLE
expression only if table department_persons
contains just a single row. If the table contains more than one row, the subquery produces an error.
Example 5-19 shows a TABLE
expression used in the FROM
clause of a SELECT
embedded in a CURSOR
expression.
Unnesting queries can be also used with multilevel collections, both varrays and nested tables. Example 5-20 shows an unnesting query on a multilevel nested table collection of nested tables. From the table region_tab
where each region has a nested table of countries
and each country has a nested table of locations
, the query returns the names of all regions
, countries
, and locations
.
Example 5-20 Unnesting Queries with Multilevel Collections Using the TABLE Function
-- Requires Ex. 5-10 and 5-15 SELECT r.region_name, c.country_name, l.location_id FROM region_tab r, TABLE(r.countries) c, TABLE(c.locations) l; -- the following query is optimized to run against the locations table SELECT l.location_id, l.city FROM region_tab r, TABLE(r.countries) c, TABLE(c.locations) l;
The output should be as follows:
REGION_NAME COUNTRY_NAME LOCATION_ID ------------------------- ---------------------------------------- ----------- Europe Italy 1000 Europe Italy 1100 Europe Switzerland 2900 Europe Switzerland 3000 Europe United Kingdom 2400 Europe United Kingdom 2500 Europe United Kingdom 2600 7 rows selected.
LOCATION_ID CITY ----------- ------------------------------ 1000 Roma 1100 Venice 2900 Geneva 3000 Bern 2400 London 2500 Oxford 2600 Stretford 7 rows selected.
Because no columns of the base table region_tab
appear in the second SELECT
list, the query is optimized to run directly against the locations
storage table.
Outer-join syntax can also be used with queries of multilevel collections. See "Viewing Object Data in Relational Form with Unnesting Queries".
Oracle supports the following DML operations on collections:
Inserts and updates that provide a new value for the entire collection
Individual or piecewise updates of nested tables and multilevel nested tables, including inserting, deleting, and updating elements
Oracle does not support piecewise updates on VARRAY
columns. However, VARRAY
columns can be inserted into or updated as an atomic unit.This section contains these topics:
For piecewise operations on nested table columns, use the TABLE
expression.
The TABLE
expression uses a subquery to extract the nested table, so that the INSERT
, UPDATE
, or DELETE
statement applies to the nested table rather than the top-level table.
CAST
operators are also helpful. With them, you can do set operations on nested tables using SQL notation, without actually storing the nested tables in the database.
The DML statements in Example 5-21 demonstrate piecewise operations on nested table columns.
Example 5-21 Piecewise Operations on Collections
-- Requires Ex. 5-1 and 5-3 INSERT INTO TABLE(SELECT d.dept_emps FROM department_persons d WHERE d.dept_no = 101) VALUES (5, 'Kevin Taylor', '1-408-555-0199'); UPDATE TABLE(SELECT d.dept_emps FROM department_persons d WHERE d.dept_no = 101) e SET VALUE(e) = person_typ(5, 'Kevin Taylor', '1-408-555-0199') WHERE e.idno = 5; DELETE FROM TABLE(SELECT d.dept_emps FROM department_persons d WHERE d.dept_no = 101) e WHERE e.idno = 5;
Example 5-22 shows VALUE
used to return object instance rows for updating:
Piecewise DML is possible only on multilevel nested tables, not on multilevel varrays. You can perform DML operation atomically on both VARRAYs and nested tables multilevel collections as described in "Collections as Atomic Data Items".
Example 5-23 shows a piecewise insert operation on the countries
nested table of nested tables. The example inserts a new country, complete with its own nested table of location_typ
:
Example 5-23 Piecewise INSERT on a Multilevel Collection
-- Requires Ex. 5-10 and 5-15 INSERT INTO TABLE( SELECT countries FROM region_tab r WHERE r.region_id = 2) VALUES ( 'CA', 'Canada', nt_location_typ( location_typ(1800, '147 Spadina Ave', 'M5V 2L7', 'Toronto', 'Ontario')));
Example 5-24 performs a piecewise insert into an inner nested table to add a location for a country. Like the preceding example, this example uses a TABLE
expression containing a subquery that selects the inner nested table to specify the target for the insert.
Example 5-24 Piecewise INSERT into an Inner Nested Table
-- Requires Ex. 5-10 and 5-15 INSERT INTO TABLE( SELECT c.locations FROM TABLE( SELECT r.countries FROM region_tab r WHERE r.region_id = 2) c WHERE c.country_id = 'US') VALUES (1700, '2004 Lakeview Rd', '98199', 'Seattle', 'Washington'); SELECT r.region_name, c.country_name, l.location_id FROM region_tab r, TABLE(r.countries) c, TABLE(c.locations) l;
This section discusses atomical changes to nested tables and VARRAY
s.
Note: While nested tables can also be changed in a piecewise fashions, varrays cannot.
Example 5-25 shows how you can manipulate SQL varray object types with PL/SQL statements. In this example, varrays are transferred between PL/SQL variables and SQL tables. You can insert table rows containing collections, update a row to replace its collection, and select collections into PL/SQL variables.
However, you cannot update or delete individual varray elements directly with SQL; you have to select the varray from the table, change it in PL/SQL, then update the table to include the new varray. You can also do this with nested tables, but nested tables have the option of doing piecewise updates and deletes.
Example 5-25 Using INSERT, UPDATE, DELETE, and SELECT Statements With Varrays
CREATE TYPE dnames_var IS VARRAY(7) OF VARCHAR2(30); / CREATE TABLE depts (region VARCHAR2(25), dept_names dnames_var); BEGIN INSERT INTO depts VALUES('Europe', dnames_var('Shipping','Sales','Finance')); INSERT INTO depts VALUES('Americas', dnames_var('Sales','Finance','Shipping')); INSERT INTO depts VALUES('Asia', dnames_var('Finance','Payroll','Shipping','Sales')); COMMIT; END; / DECLARE new_dnames dnames_var := dnames_var('Benefits', 'Advertising', 'Contracting', 'Executive', 'Marketing'); some_dnames dnames_var; BEGIN UPDATE depts SET dept_names = new_dnames WHERE region = 'Europe'; COMMIT; SELECT dept_names INTO some_dnames FROM depts WHERE region = 'Europe'; FOR i IN some_dnames.FIRST .. some_dnames.LAST LOOP DBMS_OUTPUT.PUT_LINE('dept_names = ' || some_dnames(i)); END LOOP; END; /
The section "Constructors for Multilevel Collections" shows how to insert an entire multilevel collection with an INSERT
statement. Multilevel collections (both VARRAY
and nested tables) can also be updated atomically with an UPDATE
statement. For example, suppose v_country
is a variable declared to be of the countries
nested table type nt_country_typ
.
Example 5-26 updates region_tab
by setting the countries
collection as a unit to the value of v_country
.
Example 5-26 Using UPDATE to Insert an Entire Multilevel Collection
-- Requires Ex. 5-10 and 5-15
INSERT INTO region_tab (region_id, region_name) VALUES(2, 'Americas');
DECLARE
v_country nt_country_typ;
BEGIN
v_country := nt_country_typ( country_typ(
'US', 'United States of America', nt_location_typ (
location_typ( 1500,'2011 Interiors Blvd','99236','San Francisco','California'),
location_typ(1600,'2007 Zagora St','50090','South Brunswick','New Jersey'))));
UPDATE region_tab r
SET r.countries = v_country WHERE r.region_id = 2;
END;
/
-- Invocation:
SELECT r.region_name, c.country_name, l.location_id
FROM region_tab r, TABLE(r.countries) c, TABLE(c.locations) l
WHERE r.region_id = 2;
The PL/SQL BULK
COLLECT
clause is an alternative to using DML statements, which can be time consuming to process. You can return an entire result set in one operation.
In Example 5-27, BULK
COLLECT
is used with a multilevel collection that includes an object type.
Example 5-27 Using BULK COLLECT with Collections
-- unrelated to other examples in this chapter
CREATE TYPE dnames_var IS VARRAY(7) OF VARCHAR2(30);
/
CREATE TABLE depts (region VARCHAR2(25), dept_names dnames_var);
BEGIN
INSERT INTO depts VALUES('Europe', dnames_var('Shipping','Sales','Finance'));
INSERT INTO depts VALUES('Americas', dnames_var('Sales','Finance','Shipping'));
INSERT INTO depts
VALUES('Asia', dnames_var('Finance','Payroll','Shipping','Sales'));
COMMIT;
END;
/
DECLARE
TYPE dnames_tab IS TABLE OF dnames_var;
v_depts dnames_tab;
BEGIN
SELECT dept_names BULK COLLECT INTO v_depts FROM depts;
DBMS_OUTPUT.PUT_LINE(v_depts.COUNT); -- prints 3
END;
/
The conditions listed in this section allow comparisons of nested tables, including multilevel nested tables. There is no mechanism for comparing varrays. The SQL examples in this section use the nested tables created in Example 5-5, and contain the objects created in Example 5-1.
The equal (=) and not equal (<>) conditions determine whether the input nested tables are identical or not, returning the result as a Boolean value.
Two nested tables are equal if they have the same named type, have the same cardinality, and their elements are equal. Elements are equal depending on whether they are equal by the elements own equality definitions, except for object types which require a map method. Equality is determined in the existing order of the elements, because nested tables are unordered.
Example 5-28 Using an Equality Comparison with Nested Tables
-- Requires Ex. 5-1 and 5-5 SELECT p.name FROM students, TABLE(physics_majors) p WHERE math_majors = physics_majors;
In Example 5-28, the nested tables contain person_typ
objects, which have an associated map method. See Example 5-1. Since the two nested tables in the WHERE
clause are not equal, no rows are selected.
The IN
condition checks whether or not a nested table is in a list of nested tables, returning the result as a Boolean value. NULL is returned if the nested table is a null nested table.
The SUBMULTISET
[OF]
condition checks whether or not a nested table is a subset of another nested table, returning the result as a Boolean value. The OF
keyword is optional and does not change the functionality of SUBMULTISET
.
This condition is implemented only for nested tables.
The MEMBER
[OF]
or NOT
MEMBER
[OF]
condition tests whether or not an element is a member of a nested table, returning the result as a Boolean value. The OF
keyword is optional and has no effect on the output.
In Example 5-31, the person_typ
is an element of the same type as the elements of the nested table math_majors
.
Example 5-31 Using MEMBER OF on a Nested Table
-- Requires Ex. 5-1 and 5-5 SELECT graduation FROM students WHERE person_typ(12, 'Bob Jones', '1-650-555-0130') MEMBER OF math_majors;
Example 5-32 presents an alternative approach to the MEMBER
OF
condition, which performs more efficiently for large collections.
The IS
[NOT]
EMPTY
condition checks whether a given nested table is empty or not empty, regardless of whether any of the elements are NULL. If a NULL is given for the nested table, the result is NULL. The result is returned as a Boolean value.
This section describes multiset operators for nested tables. Multiset operations are not available for varrays.
The SQL examples in this section use the nested tables created in Example 5-5 and the objects created in Example 5-1.
See Also:
|
The CARDINALITY
function returns the number of elements in a nested table. The return type is NUMBER
. If the nested table is a null collection, NULL
is returned.
Example 5-35 Determining the CARDINALITY of a Nested Table
-- Requires Ex. 5-1 and 5-5 SELECT CARDINALITY(math_majors) FROM students;
For more information about the CARDINALITY
function, see Oracle Database SQL Language Reference.
The COLLECT
function is an aggregate function which creates a multiset from a set of elements. The function takes a column of the element type as input and creates a multiset from rows selected. To get the results of this function, you must use it within a CAST
function to specify the output type of COLLECT
. See "CAST" for an example of the COLLECT
function.
For more information about the COLLECT
function, see Oracle Database SQL Language Reference.
The MULTISET
EXCEPT
operator inputs two nested tables and returns a nested table whose elements are in the first nested table but not the second. The input nested tables and the output nested table will all be of the same nested table type.
The ALL
or DISTINCT
options can be used with the operator. The default is ALL
.
With the ALL
option, for ntab1
MULTISET
EXCEPT
ALL
ntab2
, all elements in ntab1
other than those in ntab2
are part of the result. If a particular element occurs m
times in ntab1
and n
times in ntab2
, the result shows (m
- n
) occurrences of the element if m
is greater than n
, otherwise, 0
occurrences of the element.
With the DISTINCT
option, any element that is present in ntab1
and is also present in ntab2
is eliminated, irrespective of the number of occurrences.
Example 5-36 Using the MULTISET EXCEPT Operation on Nested Tables
-- Requires Ex. 5-1 and 5-5 SELECT math_majors MULTISET EXCEPT physics_majors FROM students WHERE graduation = '01-JUN-03';
For more information about the MULTISET
EXCEPT
operator, see Oracle Database SQL Language Reference.
The MULTISET
INTERSECT
operator returns a nested table whose values are common to the two input nested tables. The input nested tables and the output nested table are all type name equivalent.
There are two options associated with the operator: ALL
or DISTINCT
. The default is ALL
. With the ALL
option, if a particular value occurs m
times in ntab1
and n
times in ntab2
, the result contains the element MIN
(m
, n
) times. With the DISTINCT
option, the duplicates from the result are eliminated, including duplicates of NULL
values if they exist.
Example 5-37 Using the MULTISET INTERSECT Operation on Nested Tables
-- Requires Ex. 5-1 and 5-5 SELECT math_majors MULTISET INTERSECT physics_majors FROM students WHERE graduation = '01-JUN-03';
For more information about the MULTISET
INTERSECT
operator, see Oracle Database SQL Language Reference.
The MULTISET
UNION
operator returns a nested table whose values are those of the two input nested tables. The input nested tables and the output nested table are all type name equivalent.
There are two options associated with the operator: ALL
or DISTINCT
. The default is ALL
. With the ALL
option, all elements in ntab1
and ntab2
are part of the result, including all copies of NULL
s. If a particular element occurs m
times in ntab1
and n
times in ntab2
, the result contains the element (m
+ n
) times. With the DISTINCT
option, the duplicates from the result are eliminated, including duplicates of NULL
values if they exist.
Example 5-38 Using the MULTISET UNION Operation on Nested Tables
-- Requires Ex. 5-1 and 5-5 SELECT math_majors MULTISET UNION DISTINCT physics_majors FROM students WHERE graduation = '01-JUN-03';
PEOPLE_TYP(PERSON_TYP(12, 'Bob Jones', '1-650-555-0130'),
PERSON_TYP(31, 'Sarah Chen', '1-415-555-0120'),
PERSON_TYP(45, 'Chris Woods', '1-408-555-0128'))
-- Requires Ex. 5-1 and 5-5 SELECT math_majors MULTISET UNION ALL physics_majors FROM students WHERE graduation = '01-JUN-03';
PEOPLE_TYP(PERSON_TYP(12, 'Bob Jones', '1-650-555-0130'),
PERSON_TYP(31, 'Sarah Chen', '1-415-555-0120'),
PERSON_TYP(45, 'Chris Woods', '1-408-555-0128'),
PERSON_TYP(12, 'Bob Jones', '1-650-555-0130'),
PERSON_TYP(45, 'Chris Woods', '1-408-555-0128'))
For more information about the MULTISET
UNION
operator, see Oracle Database SQL Language Reference.
The POWERMULTISET
function generates all non-empty submultisets from a given multiset. The input to the POWERMULTISET
function can be any expression which evaluates to a multiset. The limit on the cardinality of the multiset argument is 32.
Example 5-39 Using the POWERMULTISET Operation on Multiset
-- Requires Ex. 5-1 and 5-5 SELECT * FROM TABLE(POWERMULTISET( people_typ ( person_typ(12, 'Bob Jones', '1-650-555-0130'), person_typ(31, 'Sarah Chen', '1-415-555-0120'), person_typ(45, 'Chris Woods', '1-415-555-0124'))));
For more information about the POWERMULTISET
function, see Oracle Database SQL Language Reference.
The POWERMULTISET_BY_CARDINALITY
function returns all non-empty submultisets of a nested table of the specified cardinality. The output is rows of nested tables.
POWERMULTISET_BY_CARDINALITY(x, l)
is equivalent to TABLE(POWERMULTISET(x))
p
where CARDINALITY(value(p))
=
l
, where x
is a multiset and l is the specified cardinality.
The first input parameter to the POWERMULTISET_BY_CARDINALITY
can be any expression which evaluates to a nested table. The length parameter must be a positive integer, otherwise an error is returned. The limit on the cardinality of the nested table argument is 32.
Example 5-40 Using the POWERMULTISET_BY_CARDINALITY Function
-- Requires Ex. 5-1 and 5-5 SELECT * FROM TABLE(POWERMULTISET_BY_CARDINALITY( people_typ ( person_typ(12, 'Bob Jones', '1-650-555-0130'), person_typ(31, 'Sarah Chen', '1-415-555-0120'), person_typ(45, 'Chris Woods', '1-415-555-0124')),2));
For more information about the POWERMULTISET_BY_CARDINALITY
function, see Oracle Database SQL Language Reference.
The SET
function converts a nested table into a set by eliminating duplicates, and returns a nested table whose elements are distinct from one another. The nested table returned is of the same named type as the input nested table.
Example 5-41 Using the SET Function on a Nested Table
-- Requires Ex. 5-1 and 5-5 SELECT SET(physics_majors) FROM students WHERE graduation = '01-JUN-03';
For more information about the SET
function, see Oracle Database SQL Language Reference.
Partitioning addresses the key problem of supporting very large tables and indexes by allowing you to decompose them into smaller and more manageable pieces called partitions. Oracle extends partitioning capabilities by letting you partition tables that contain objects, REF
s, varrays, and nested tables. Varrays stored in LOB
s are equipartitioned in a way similar to LOB
s. See also Oracle Database SecureFiles and Large Objects Developer's Guide.
With Oracle Database 11g release 1 (11.1), nested tables are equipartitioned, meaning that the partitioning of storage tables associated with nested tables corresponds to that of the top level base tables. The keyword LOCAL
is the default and indicates this behavior. Previous releases stored unpartitioned nested tables with partitioned base tables. To obtain this behavior, specify the GLOBAL
keyword. To partition your existing non-partitioned nested tables, see the discussion of online redefinition in Oracle Database VLDB and Partitioning Guide.
Generally, maintenance operations are carried out on the top level (or parent table) and cascade to the associated nested tables. However, you must perform the following operations directly on the nested table partition:
Modifying default attributes, that is, changing default physical attributes of a partition.
Modifying a partition, that is, changing the physical attributes of a table partition.
Moving a partition, that is, moving contents of a table partition into another segment or another tablespace.
Renaming a partition, that is, assigning a new name to a table partition.
See Also: For further information on equipartitioning |
Example 5-42 partitions the purchase order table along zip codes (ToZip
), which is an attribute of the ShipToAddr
embedded column object. The LineItemList_nt
nested table illustrates storage for the partitioned nested table.
Example 5-42 Partitioning a Nested Table That Contains Objects
CREATE TYPE StockItem_objtyp AS OBJECT ( StockNo NUMBER, Price NUMBER, TaxRate NUMBER); / CREATE TYPE LineItem_objtyp AS OBJECT ( LineItemNo NUMBER, Stock_ref REF StockItem_objtyp, Quantity NUMBER, Discount NUMBER); / CREATE TYPE Address_objtyp AS OBJECT ( Street VARCHAR2(200), City VARCHAR2(200), State CHAR(2), Zip VARCHAR2(20)) / CREATE TYPE LineItemList_nt as table of LineItem_objtyp; / CREATE TYPE PurchaseOrder_ntyp AS OBJECT ( PONo NUMBER, OrderDate DATE, ShipDate DATE, OrderForm BLOB, LineItemList LineItemList_nt, ShipToAddr Address_objtyp, MAP MEMBER FUNCTION ret_value RETURN NUMBER, MEMBER FUNCTION total_value RETURN NUMBER); / CREATE TABLE PurchaseOrders_ntab of PurchaseOrder_ntyp LOB (OrderForm) store as (nocache logging) NESTED TABLE LineItemList STORE AS LineItemList_ntab PARTITION BY RANGE (ShipToAddr.zip) (PARTITION PurOrderZone1_part VALUES LESS THAN ('59999') LOB (OrderForm) store as ( storage (INITIAL 10 MINEXTENTS 10 MAXEXTENTS 100)) NESTED TABLE LineItemList store as LineitemZone1_part( storage (INITIAL 10 MINEXTENTS 10 MAXEXTENTS 100)), PARTITION PurOrderZone2_part VALUES LESS THAN ('79999') LOB (OrderForm) store as ( storage (INITIAL 10 MINEXTENTS 10 MAXEXTENTS 100)) NESTED TABLE LineItemList store as LineitemZone2_part( storage (INITIAL 10 MINEXTENTS 10 MAXEXTENTS 100)), PARTITION PurOrderZone3_part VALUES LESS THAN ('99999') LOB (OrderForm) store as ( storage (INITIAL 10 MINEXTENTS 10 MAXEXTENTS 100)) NESTED TABLE LineItemList store as LineitemZone3_part( storage (INITIAL 10 MINEXTENTS 10 MAXEXTENTS 100)) ) /
The previous chapters in this book discuss topics that you need to get started with Oracle objects. The topics in this chapter are of interest once you start applying object-relational techniques to large-scale applications or complex schemas.
The chapter contains these topics:
Oracle database automatically maps the complex structure of object types into simple table structure for storage.
This section discusses these related topics:
An object type is like a tree structure, where the branches represent the attributes. Attributes that are objects sprout subbranches with their own attributes.
Ultimately, each branch ends at an attribute that is a built-in type; such as NUMBER
, VARCHAR2
, or REF
, or a collection type, such as VARRAY
or nested table. Each of these leaf-level attributes of the original object type is stored in a table column.
Leaf-level attributes that are not collection types are called the leaf-level scalar attributes of the object type.
The following topics relate to the discussion of object tables and relational tables in "How Objects are Stored in Tables".
In an object table, Oracle database stores the data for every leaf-level scalar or REF
attribute in a separate column.
Note: EachVARRAY is also stored in a column, unless it is too large. Oracle database stores leaf-level attributes of nested table types in separate tables associated with the object table. You must declare these tables as part of the object table declaration. See "Internal Layout of VARRAYs" and "Internal Layout of Nested Tables". |
When you retrieve or change attributes of row objects in an object table, the database performs the corresponding operations on the columns of the table. Accessing the value of the row object itself invokes the default constructor for the type, using the columns of the object table as arguments and produces a copy of the object.
The database stores the system-generated object identifier in a hidden column. The database uses the object identifier to construct REF
s to the object.
When a table (relational table) is defined with a column of an object type, the database adds hidden columns to the table for the leaf-level attributes of the object type. Each object-type column also has a corresponding hidden column to store the NULL information for the column objects (that is, the atomic nulls of the top-level and the nested objects).
A substitutable column or object table has a hidden column not only for each attribute of the object type of the column but also for each attribute added in any subtype of the object type. These columns store the values of those attributes for any subtype instances inserted in the substitutable column.
Besides the type-discriminant column and the null-image column, the following are associated with a substitutable column of person_typ
, created by Example 8-1
A hidden column for each of the attributes of person_typ
: idno
, name
, and phone
Hidden columns for attributes of the subtypes of person_typ
Thus, the following might be associated with a substitutable column of person_typ
: the attributes dept_id
and major
(for student_typ
) and number_hours
(for part_time_student_typ
).
When you create a subtype, the database automatically adds hidden columns for new attributes in the subtype to tables containing a substitutable column of any of the ancestor types of the new subtype. These retrofit the tables to store data of the new type. If, for some reason, the columns cannot be added, creation of the subtype is rolled back.
When you drop a subtype using DROP TYPE
with the VALIDATE
option, the database automatically drops hidden columns for attributes unique to the subtype that do not contain data. Errors are raised if these columns contain data.
Example 8-1 creates types needed for subsequent examples in this chapter
Example 8-1 Creating Types and Inserting in Tables
-- drop any of these objects created for Ex.7-10 CREATE TYPE person_typ AS OBJECT ( idno NUMBER, name VARCHAR2(30), phone VARCHAR2(20), MAP MEMBER FUNCTION get_idno RETURN NUMBER ) NOT FINAL; / CREATE TYPE BODY person_typ AS MAP MEMBER FUNCTION get_idno RETURN NUMBER IS BEGIN RETURN idno; END; END; / CREATE TYPE student_typ UNDER person_typ ( dept_id NUMBER, major VARCHAR2(30)) NOT FINAL; / CREATE TYPE part_time_student_typ UNDER student_typ ( number_hours NUMBER); / CREATE TYPE employee_typ UNDER person_typ ( emp_id NUMBER, mgr VARCHAR2(30)); / CREATE TABLE person_obj_table OF person_typ; // an object table INSERT INTO person_obj_table VALUES (person_typ(12, 'Bob Jones', '650-555-0130')); INSERT INTO person_obj_table VALUES (student_typ(51, 'Joe Lane', '1-650-555-0140', 12, 'HISTORY')); INSERT INTO person_obj_table VALUES (part_time_student_typ(52, 'Kim Patel', '1-650-555-0135', 14, 'PHYSICS', 20));
Substitutable columns are associated with hidden type-discriminant columns. The hidden columns contains an identifier, called a typeid, that identifies the most specific type of each object in the substitutable columns. Typically, a typeid (RAW
) is one byte, though it can be as big as four bytes for a large hierarchy.
You can find the typeid of a specified object instance using the function SYS_TYPEID
.
Example 8-2 retrieves typeids of object instances stored in the substitutable object table created in Example 8-1:
Example 8-2 Querying for Typeids of Objects Stored in the Table
-- Requires Ex. 8-1
SELECT name, SYS_TYPEID(VALUE(p)) typeid
FROM person_obj_table p;
NAME TYPEID
------------------------------ ---------------------------
Bob Jones 01
Joe Lane 02
Kim Patel 03
The catalog views USER_TYPES
, DBA_TYPES,
and ALL_TYPES
contain a TYPEID
column (not hidden) that gives the typeid value for each type. You can join on this column to get the type names corresponding to the typeids in a type-discriminant column.
See Also: "SYS_TYPEID" for more information aboutSYS_TYPEID , typeids, and type-discriminant columns. |
When the database constructs a REF
to a row object, the constructed REF
is made up of the object identifier (OID), 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 requirements associated with the column, as follows:
If the column is declared as a REF
WITH
ROWID
, the database stores the ROWID
in the REF
column. The ROWID
hint is ignored for object references in constrained REF
columns.
If a column is declared as a REF
with a SCOPE
clause, the column decreases due to the omission of the object table metadata and the ROWID
. A scoped REF
is 16 bytes long.
If the object identifier is primary-key based, the database may create one or more internal columns to store the values of the primary key, depending on how many columns comprise the primary key.
Note: When aREF column references row objects whose object identifiers are derived from primary keys, it is referred to as a primary-key-based REF or pkREF . Columns containing pkREF s must be scoped or have a referential constraint. |
The rows of a nested table are stored in a separate storage table. Each nested table column has a single associated storage table. The storage table holds all the elements for all of the nested tables in that column. The storage table has a hidden NESTED_TABLE_ID
column with a system-generated value that lets Oracle database map the nested table elements back to the appropriate row.
You can speed up queries that retrieve entire collections by making the storage table index-organized. Include the ORGANIZATION INDEX
clause inside the STORE AS
clause.
A nested table type can contain objects or scalars:
If the elements are objects, the storage table is like an object table: the top-level attributes of the object type become the columns of the storage table. However, you cannot construct REF
s to objects in a nested table because a nested table row has no object identifier column.
If the elements are scalars, the storage table contains a single column called COLUMN_VALUE
that contains the scalar values.
All the elements of a VARRAY
are stored in a single column. Depending upon the size of the array, it may be stored inline or in a BLOB
. See Storage Considerations for Varrays for details.
This section discusses the use of indexes on typeids and attributes.
This section contains the following topics:
Using the SYS_TYPEID
function, you can build an index on the hidden type-discriminant column of substitutable columns. The type-discriminant column contains typeids that identify the most specific type of every object instance stored in the substitutable column. The system uses this information to evaluate queries that filter by type using the IS OF
predicate, but you can access the typeids for your own purposes using the SYS_TYPEID
function.
Generally, a type-discriminant column contains only a small number of distinct typeids: at most, there can be only as many as there are types in the related type hierarchy. The low cardinality of this column makes it a good candidate for a bitmap index.
For example, the following statement creates a bitmap index on the type-discriminant column underlying the substitutable contact
column of table contacts
. The function SYS_TYPEID
references the type-discriminant column:
Example 8-3 Create bitmap index on type-discriminant column
-- Requires Ex. 8-1 CREATE TABLE contacts ( contact person_typ, contact_date DATE ); INSERT INTO contacts VALUES ( person_typ (65,'Vrinda Mills', '1-650-555-0125'),'24 Jun 2003' ); INSERT INTO contacts VALUES ( person_typ (12, 'Bob Jones', '650-555-0130'),'24 Jun 2003' ); INSERT INTO contacts VALUES ( student_typ(51, 'Joe Lane', '1-650-555-0140', 12, 'HISTORY'),'24 Jun 2003' ); INSERT INTO contacts VALUES ( part_time_student_typ(52, 'Kim Patel', '1-650-555-0135', 14, 'PHYSICS', 20),'24 Jun 2003' ); CREATE BITMAP INDEX typeid_idx ON contacts (SYS_TYPEID(contact));
You can build an index on attributes for any types that can be stored in a substitutable column. You can reference attributes of subtypes in the CREATE INDEX
statement by filtering out types other than the desired subtype (and its subtypes) using the TREAT
function; you then use dot notation to specify the desired attribute.
For example, the following statement creates an index on the major
attribute of all students in the contacts
table. The declared type of the contact
column is person_typ
, of which student_typ
is a subtype, so the column may contain instances of person_typ
, student_typ
, and subtypes of either one:
Example 8-4 Create index on attribute of all students
-- Requires Ex.8-1- and 8-3 CREATE INDEX major1_idx ON contacts (TREAT(contact AS student_typ).major);
The student_typ
type first defined the major
attribute: the person_typ
supertype does not have it. Consequently, all the values in the hidden column for the major
attribute are values for persons of type student_typ
or parttimestudent_typ
(a student_typ
subtype). This means that the values of the hidden column are identical to the values returned by the TREAT
expression, major
values for all students, including student subtypes: both the hidden column and the TREAT
expression list majors for students and nulls for non-students. The system exploits this fact and creates index major1_idx
as an ordinary B-tree index on the hidden column.
Values in a hidden column are only identical to the values returned by the TREAT
expression just described if the type named as the target of the TREAT
function (student_typ
) is the type that first defined the major
attribute. If the target of the TREAT
function is a subtype that merely inherited the attribute, as in the following example, the TREAT
expression returns non-null major
values for the subtype (part-time students) but not for its supertype (other students).
CREATE INDEX major2_idx ON contacts (TREAT(contact AS part_time_student_typ).major);
Here, the values stored in the hidden column for major
may be different from the results of the TREAT
expression. Consequently, an ordinary B-tree index cannot be created on the underlying column. Therefore, the database treats the TREAT
expression like any other function-based expression and tries to create the index as a function-based index on the result.
The following example, like the previous one, creates a function-based index on the major
attribute of part-time students, but in this case, the hidden column for major
is associated with a substitutable object table person_obj_table
:
CREATE INDEX major3_idx ON person_obj_table p (TREAT(VALUE(p) AS part_time_student_typ).major);
Type evolution is the process of changing a object type. You can make the following changes to an object type:
Add and drop attributes
Add and drop methods
Modify a numeric attribute to increase its length, precision, or scale
Modify a varying length character attribute to increase its length
Change the FINAL
and INSTANTIABLE
properties of a type
Modify limit and size of VARRAY
s
Modify length, precision, and scale of collection elements
Changes to a type affect things that reference the type. For example, if you add a new attribute to a type, data in a column of that type must be presented so as to include the new attribute.
This section includes the following topics:
Dependent schema objects of a type are objects that directly or indirectly reference the type and are affected by a change to it.
A type can have these kinds of dependent schema objects: tables; types or subtypes; program units (PL/SQL blocks) such as procedures, functions, packages, and triggers; indextypes; views (including object views); function-based indexes; and operators.
How a dependent schema object is affected by a change to a type depends on the object and on the nature of the change.
Dependent program units, views, operators, and indextypes are marked invalid when the type is modified. The next time one of these invalid schema objects is referenced, it is revalidated using the new type definition. If the object recompiles successfully, it becomes valid and can be used again.
Dependent function-based indexes may be dropped or disabled, depending on the type change, and must be rebuilt.
Dependent tables have one or more internal columns added for each attribute added to the type, depending on the attribute type. New attributes are added with NULL
values. For each dropped attribute, the columns associated with that attribute are dropped. For each modified attribute, the length, precision, or scale of its associated column is changed accordingly.
These changes mainly involve updating the metadata of the tables and can be performed quickly. However, the data in those tables must be updated to the format of the new type version as well, as discussed in "Options for Updating Data".
Depending on the amount of data, updating can be time-consuming, so the ALTER TYPE
command has options to let you choose whether to convert all dependent table data immediately or to leave it in the old format to be converted piecemeal as it is updated in the course of business.
The CASCADE
option for ALTER TYPE
propagates a type change to dependent types and tables. See "ALTER TYPE Statement for Type Evolution". CASCADE
itself has the following options that let you choose whether or not to convert table data to the new type format as part of the propagation:
INCLUDING TABLE DATA
: converts the data (default)
NOT INCLUDING TABLE DATA
: does not convert data
By default, the CASCADE
option converts the data. In either case, table data is always returned in the format of the latest type version. If the table data is stored in the format of an earlier type version, the database converts the data to the format of the latest version before returning it, even though the format in which the data is actually stored is not changed until the data is rewritten.
You can retrieve the definition of the latest type from the system view USER_SOURCE
. You can view definitions of all versions of a type in the USER_TYPE_VERSIONS
view.
See Also: Oracle Database PL/SQL Language Reference for details about type specification and body compilation |
Structural changes to a type affect dependent data and require the data to be converted. This is not true for changes that are confined to method definitions or behavior (implementation) of the type.
These possible changes to a type are structural:
Add or drop an attribute
Modify the length, precision, or scale of an attribute
Change the finality of a type from FINAL
to NOT FINAL
or the reverse
These changes result in new versions of the altered type and all its dependent types and require the system to add, drop, or modify internal columns of dependent tables as part of the process of converting to the new version.
When you make any of these kinds of changes to a type that has dependent types or tables, the effects of propagating the change are not confined only to metadata but also affect data storage arrangements and require data conversion.
Besides converting data, you may also need to make other changes. For example, if a new attribute is added to a type, and the type body invokes the constructor of the type, then each constructor in the type body must be modified to specify a value for the new attribute. Similarly, if a new method is added, then the type body must be replaced to add the implementation of the new method. The type body can be modified by using the CREATE OR REPLACE TYPE BODY
statement.
Example 8-5 illustrates how to make a simple change to person_typ
by adding one attribute and dropping another. The CASCADE
keyword propagates the type change to dependent types and tables, but the phrase NOT
INCLUDING
TABLE
DATA
prevents conversion of the related data.
Example 8-5 Altering an Object Type by Adding and Dropping an Attribute
-- Drop person_typ and person_obj_table if they exist CREATE TYPE person_typ AS OBJECT ( idno NUMBER, name VARCHAR2(30), phone VARCHAR2(20)); / CREATE TABLE person_obj_table OF person_typ; INSERT INTO person_obj_table VALUES (person_typ(12, 'Bob Jones', '650-555-0130')); SELECT value(p) FROM person_obj_table p;
VALUE(P)(IDNO, NAME, PHONE)
--------------------------------------------
PERSON_TYP(12, 'Bob Jones', '650-555-0130')
You can add the email attribute and drop the phone attribute as follows:
ALTER TYPE person_typ ADD ATTRIBUTE (email VARCHAR2(80)), DROP ATTRIBUTE phone CASCADE NOT INCLUDING TABLE DATA;
Then disconnect and reconnect to accommodate the type change:
connect oe/oe; connect hr/hr; ALTER SESSION SET PLSQL_WARNINGS = 'enable:all'; -- The data of table person_obj_table has not been converted yet, but -- when the data is retrieved, Oracle returns the data based on -- the latest type version. The new attribute is initialized to NULL. SELECT value(p) FROM person_obj_table p;
VALUE(P)(IDNO, NAME, EMAIL)
---------------------------------
PERSON_TYP(12, 'Bob Jones', NULL)
During SELECT
statements, even though column data may be converted to the latest type version, the converted data is not written back to the column. If you retrieve a particular user-defined type column in a table often, consider converting that data to the latest type version to eliminate redundant data conversions. Converting is especially beneficial if the column contains VARRAY
attributes which typically take more time to convert than objects or nested table columns.
You can convert a column of data by issuing an UPDATE
statement to set the column to itself, as indicated in the following code snippet, which is unrelated to previous code.
UPDATE dept_tab SET emp_array_col = emp_array_col;
You can convert all columns in a table by using ALTER
TABLE
with the UPGRADE
INCLUDING
DATA
. For example:
ALTER TYPE person_typ ADD ATTRIBUTE (photo BLOB) CASCADE NOT INCLUDING TABLE DATA; ALTER TABLE person_obj_table UPGRADE INCLUDING DATA;
The ALTER
TABLE
line converts only the table listed. The CASCADE
option prevents conversion of other tables or dependents.
This section describes the steps required to make a c omplex change to a type: the addition of a nested table attribute to an object type that is included in a nested table.
Example 8-6 provides the initial schema which is altered by Example 8-7.
Example 8-6 Initial Schema
-- Drop existing person_typ, department_type, people_typ objects or tables CREATE TYPE person_typ AS OBJECT ( idno NUMBER, name VARCHAR2(30), phone VARCHAR2(20)); / -- creating a nested table type CREATE TYPE people_typ AS TABLE OF person_typ;/ CREATE TYPE department_typ AS OBJECT ( manager person_typ, employee people_typ); // a nested table/ CREATE TABLE department OF department_typ NESTED TABLE employee STORE AS employee_store_nt;
Example 8-7 starts by creating a new object tasks_typ
and a nested table type to hold it, tasks_nttab
.
The following steps, both in Example 8-7, and in other programs, are necessary to add the nested table tasks
as an attribute to the object type person_typ
, which is already included in the nested table people_typ
.
Issue an ALTER TYPE..INVALIDATE
statement to alter the type person_typ
. This statement bypasses all type and table checks to save time and invalidates dependent objects. You cannot access table data until it is validated.
The ALTER
TYPE
statement includes ADD
ATTRIBUTE
to add the nested table tasks
.
The UPGRADE.. STORE AS
clause upgrades the affected nested table, and specifies name of the new storage table.
Example 8-7 Altering an Object Type by Adding a Nested Table Attribute
-- Requires Ex. 8-6 CREATE TYPE tasks_typ AS OBJECT ( priority VARCHAR2(2), description VARCHAR2(30)); / CREATE TYPE tasks_nttab AS TABLE OF tasks_typ; / ALTER TYPE person_typ ADD ATTRIBUTE tasks tasks_nttab INVALIDATE; -- Propagate the change to employee_store_nt -- Specify a storage name for the new nested table ALTER TABLE employee_store_nt UPGRADE NESTED TABLE tasks STORE AS tasks_nt;
Use CREATE OR REPLACE TYPE BODY
for person_typ
to update the corresponding type body to make it current with the new type definition, if necessary.
Upgrade the dependent tables to the latest type version and convert the data in the tables. This validates the table and allow for data access again.
ALTER TABLE department UPGRADE INCLUDING DATA;
Alter dependent PL/SQL program units as needed to take account of changes to the type.
Use OTT or JPublisher to generate new header files for applications, depending on whether the application is written in C or Java.
Adding a new attribute to a supertype also increases the number of attributes in all its subtypes because these inherit the new attribute. Inherited attributes always precede declared (locally defined) attributes, so adding a new attribute to a supertype causes the ordinal position of all declared attributes of any subtype to be incremented by one recursively. The mappings of the altered type must be updated to include the new attributes. Oracle Type Translator (OTT) and JPublisher do this. If you use another tool, you must be sure that the type headers are properly synchronized with the type definition in the server; otherwise, unpredictable behavior may result.
Modify application code as needed and rebuild the application.
When the system executes an ALTER TYPE
statement, it first validates the requested type change syntactically and semantically to make sure it is legal. The system performs the same validations as for a CREATE TYPE
statement plus some additional ones. If the new spec of the target type or any of its dependent types fails the type validations, the ALTER TYPE
statement aborts. No new type version is created, and all dependent objects remain unchanged.
If dependent tables exist, further checking ensures that restrictions relating to the tables and indexes are observed. For example, it ensures that an attribute being dropped is not used as a partitioning key. Again, if the ALTER TYPE
statement fails the check of table-related restrictions, then the type change is aborted, and no new version of the type is created.
When a single ALTER TYPE
statement adds multiple attributes, it is done in the order specified. Multiple type changes can be specified in the same ALTER TYPE
statement, but no attribute name or method signature can be specified more than once in the statement. For example, adding and modifying the same attribute in a single statement is not allowed.
The following sections contain other notes on type changes including:
Dropping an Attribute
Dropping all attributes from a root type is not allowed. Instead, you must drop the type. Because a subtype inherits all the attributes from its supertype, dropping all the attributes from a subtype does not reduce its attribute count to zero; therefore, dropping all attributes declared locally in a subtype is allowed.
Only an attribute declared locally in the target type can be dropped. You cannot drop an inherited attribute from a subtype. Instead, drop the attribute from the type where it is locally declared.
Dropping an attribute which is part of a table partitioning or sub-partitioning key in a table is not allowed.
Dropping an attribute of a primary key OID of an object table or an index-organized table (IOT) is not allowed.
When an attribute is dropped, the column corresponding to the dropped attribute is dropped.
When an attribute is dropped, any indexes, statistics, constraints, and referential integrity constraints that reference it are removed.
Modifying the Length, Precision, or Scale of an Attribute Type
You are not allowed to expand the length of an attribute referenced in a function-based index, clustered key or domain index on a dependent table.
You are not allowed to decrease the length, precision, or scale of an attribute.
You can only drop a method from the type in which the method is defined (or redefined): You cannot drop an inherited method from a subtype, and you cannot drop an redefined method from a supertype.
If a method is not redefined, dropping it using the CASCADE
option removes the method from the target type and all subtypes. However, if a method is redefined in a subtype, the CASCADE
will fail and roll back. For the CASCADE
to succeed, you must first drop each redefined method from the subtype that defines it and then drop the method from the supertype.
You can consult the USER_DEPENDENCIES
table to find all the schema objects, including types, that depend on a given type. You can also run the DBMS_UTILITY.GET_DEPENDENCY
utility to find the dependencies of a type.
You can use the INVALIDATE
option to drop a method that has been redefined, but the redefined versions in the subtypes must still be dropped manually. The subtypes will remain in an invalid state until they are explicitly altered to drop the redefined versions. Until then, an attempt to recompile the subtypes for revalidation will produce the error Method does not override
.
Unlike CASCADE
, INVALIDATE
bypasses all the type and table checks and simply invalidates all schema objects dependent on the type. The objects are revalidated the next time they are accessed. This option is faster than using CASCADE
, but you must be certain that no problems occur when revalidating dependent types and tables. Table data cannot be accessed while a table is invalid; if a table cannot be validated, its data remains inaccessible.
Modifying the INSTANTIABLE Property
Altering an object type from INSTANTIABLE
to NOT INSTANTIABLE
is allowed only if the type has no table dependents.
Altering an object type from NOT INSTANTIABLE
to INSTANTIABLE
is allowed anytime. This change does not affect tables.
Altering an object type from NOT FINAL
to FINAL
is only allowed if the target type has no subtypes.
When you alter an object type from FINAL
to NOT FINAL
or vice versa, you must use CASCADE
to convert data in dependent columns and tables immediately. You may not use the CASCADE
option NOT INCLUDING TABLE DATA
to defer converting data.
From NOT FINAL
to FINAL
, you must use CASCADE INCLUDING TABLE DATA
.
From FINAL
to NOT FINAL
, you may use either CASCADE INCLUDING TABLE DATA
or CASCADE CONVERT TO SUBSTITUTABLE
.
When you alter a type from FINAL
to NOT
FINAL
, select the CASCADE
option based on whether or not you want to insert new subtypes of the altered types into existing columns and tables.
By default, altering a type from FINAL
to NOT
FINAL
enables you to create new substitutable tables and columns of that type, but it does not automatically make existing columns (or object tables) of that type substitutable. In fact, just the opposite happens: existing columns and tables of the type are marked NOT SUBSTITUTABLE
AT
ALL
LEVELS
. If any embedded attribute of these columns is substitutable, an error is generated. New subtypes of the altered type cannot be inserted into these preexisting columns and tables.
To alter an object type to NOT
FINAL
in a way that makes existing columns and tables of the type substitutable (assuming that they are not marked NOT
SUBSTITUTABLE
), use the CASCADE
option CONVERT TO SUBSTITUTABLE
.
Example 8-8 shows the use of CASCADE
with the option CONVERT TO SUBSTITUTABLE
:
Example 8-8 Converting a Type from FINAL to NOT FINAL
CREATE TYPE shape AS OBJECT (
name VARCHAR2(30),
area NUMBER)
FINAL;/
ALTER TYPE shape NOT FINAL CASCADE CONVERT TO SUBSTITUTABLE;
This CASCADE
option marks each existing column as SUBSTITUTABLE AT ALL LEVELS
and causes a new, hidden column to be added for the TypeId of instances stored in the column. The column can then store subtype instances of the altered type.
The INVALIDATE
option of the ALTER
TYPE
statement lets you alter a type without propagating the type change to dependent objects. In this case, the system does not validate the dependent types and tables, that is, does not ensure that all the ramifications of the type change are legal. Instead, the system marks all dependent schema objects invalid. These objects, including types and tables, are revalidated the next time they are referenced. If a type cannot be revalidated, it remains invalid, and any tables referencing it become inaccessible until the problem is corrected.
A table may fail validation for reasons such as: the addition of a new attribute to a type increased the number of columns in the table beyond the maximum of 1000, or an attribute used as a partitioning or clustering key of a table was dropped from a type.
To force a revalidation of a type, users can issue the ALTER TYPE COMPILE
statement. To force a revalidation of an invalid table, users can issue the ALTER TABLE UPGRADE
statement and specify whether or not the data is to be converted to the latest type version.
Note: In a system-triggered table validation, the table is referenced, table data is always updated to the latest type version: you do not have the option to postpone conversion of the data. |
If a table cannot be converted to the latest type version, then INSERT
, UPDATE
and DELETE
statements on the table are not allowed, and the table data becomes inaccessible. The following DDLs can be executed on the table, but all other statements which reference an invalid table are not allowed until the table is successfully validated:
DROP TABLE
TRUNCATE TABLE
All PL/SQL programs containing variables defined using %ROWTYPE
of a table or %TYPE
of a column or attribute from a table are compiled based on the latest type version. If the table fails the revalidation, then compiling any program units that reference that table also fails.
Table 8-1 lists some of the important options in the ALTER
TYPE
and ALTER
TYPE
...CASCADE
statements for altering the attribute or method definition of a type.
Table 8-1 ALTER TYPE Options for Type Evolution
Option | Description |
---|---|
|
Invalidates all dependent objects. Use this option to bypass all the type and table checks, and save time. Use this option only if you are certain that problems will not be encountered revalidating dependent types and tables. Table data cannot be accessed again until it is validated; if it cannot be validated, it remains inaccessible. |
|
Propagates the type change to dependent types and tables. The statement aborts if an error is found in dependent types or tables unless the If |
|
Converts data stored in all user-defined columns to the most recent version of the column type. For each new attribute added to the column type, a new attribute is added to the data and is initialized to |
|
Leaves column data as is, does not change type version. If an attribute is dropped from a type referenced by a table, the corresponding column of the dropped attribute is not removed from the table. However, the metadata of the column is marked unused. If the dropped attribute is stored out-of-line (for example, This option is useful when you have many large tables and may run out of rollback segments if you convert them all in one transaction. This option enables you to convert the data of each dependent table later in a separate transaction (using an Specifying this option speeds up the table upgrade because the table data remains in the format of the old type version. However, selecting data from this table requires converting the images stored in the column to the latest type version. This is likely to affect performance during subsequent Because this option only requires updating the table metadata, it does not require that all tablespaces be on-line in read/write mode for the statement to succeed. |
|
Forces the system to ignore errors from dependent tables and indexes. Errors are logged in a specified exception table so that they can be queried afterward. Use this option with caution because dependent tables can become inaccessible if some table errors occur. |
|
For use when altering a type from If the type is altered to |
You can use ALTER
TABLE
to convert table data to the latest version of referenced types. For an example, see "Altering a Type by Adding a Nested Table Attribute". See Table 8-1 for a discussion of the INCLUDING
DATA
option.
This section discusses various aspects of using system-defined constructors, also known as attribute-value constructors, and user-defined constructors.
This section includes these topics:
The system-defined constructor, also known as the attribute-value constructor, requires you to pass the constructor a value for each attribute of the type. The constructor then sets the attributes of the new object instance to those values, as shown in Example 8-9.
Example 8-9 Setting the attribute-value with the Constructor
CREATE TYPE shape AS OBJECT (
name VARCHAR2(30),
area NUMBER);
/
CREATE TABLE building_blocks of shape;
-- attribute-value constructor: Sets instance attributes to the specified values
INSERT INTO building_blocks
VALUES (
NEW shape('my_shape', 4));
The keyword NEW
preceding a call to a constructor is optional but recommended.
The attribute-value constructor saves you the trouble of defining your own constructors for a type. However, you must supply a value for every attribute declared in the type or the constructor call fails to compile.
This requirement can create a problem if you evolve the type later on, especially because the attribute-value constructor is implicit and not visible in the code, unlike a user-defined constructor. When you change the attributes of a type, the attribute-value constructor of the type changes, too. If you add an attribute, the updated attribute-value constructor expects a value for the new attribute; otherwise, any attribute-value constructor calls in your existing code fail.
See "Type Evolution".
User-defined constructors do not need to explicitly set a value for every attribute of a type, unlike attribute-value constructors. A user-defined constructor can have any number of arguments, of any type, and these do not need to map directly to type attributes. When you define a constructor, you can initialize the attributes to any appropriate values. For any attributes which you do not supply values, the system initialized to NULL
.
If you evolve a type—for example, by adding an attribute—calls to user-defined constructors for the type do not need to be changed. User-defined constructors are not automatically modified when the type evolves, so their signatures remain the same. You may, however, need to change the definition of the constructor if you do not want the new attribute to be initialized to NULL
.
You define user-defined constructors in the type body, like an ordinary method. You introduce the declaration and the definition with the phrase CONSTRUCTOR FUNCTION
and end with the clause RETURN SELF AS RESULT
.
A constructor for a type must have the same name as the type. Example 8-10 defines two constructor functions for the shape
type. As the example shows, you can overload user-defined constructors by defining multiple versions with different signatures.
Example 8-10 Defining and Implementing User-Defined Constructors
CREATE TYPE shape AS OBJECT ( name VARCHAR2(30), area NUMBER, CONSTRUCTOR FUNCTION shape(SELF IN OUT NOCOPY shape, name VARCHAR2) RETURN SELF AS RESULT, CONSTRUCTOR FUNCTION shape(SELF IN OUT NOCOPY shape, name VARCHAR2, area NUMBER) RETURN SELF AS RESULT ) NOT FINAL; / CREATE TYPE BODY shape AS CONSTRUCTOR FUNCTION shape(SELF IN OUT NOCOPY shape, name VARCHAR2) RETURN SELF AS RESULT IS BEGIN SELF.name := name; SELF.area := 0; RETURN; END; CONSTRUCTOR FUNCTION shape(SELF IN OUT NOCOPY shape, name VARCHAR2, area NUMBER) RETURN SELF AS RESULT IS BEGIN SELF.name := name; SELF.area := area; RETURN; END; END; /
A user-defined constructor has an implicit first parameter SELF
. Specifying this parameter in the declaration of a user-defined constructor is optional. If you do specify it, you must declare its mode to be IN OUT
.
The required clause RETURN SELF AS RESULT
ensures that the most specific type of the instance being returned is the same as the most specific type of the SELF
argument. In the case of constructors, this is the type for which the constructor is defined. For example, if the most specific type of the SELF
argument on a call to the shape
constructor is shape
, then this clause ensures that the shape
constructor returns an instance of shape
(not an instance of a subtype of shape
).
When a constructor function is called, the system initializes the attributes of the SELF
argument to NULL
. Names of attributes subsequently initialized in the function body may be qualified with SELF
, such as SELF.name
in Example 8-10, to distinguish them from the names of the arguments of the constructor function, if these are the same. If the argument names are different, this qualification is not necessary.
The function body must include an explicit return;
as shown. The return keyword must not be followed by a return
expression. The system automatically returns the newly constructed SELF
instance.
A user-defined constructor may be implemented in PL/SQL, C, or Java.
You can overload user-defined constructors, like other type methods.
User-defined constructors are not inherited, so a user-defined constructor defined in a supertype cannot be hidden in a subtype. However, a user-defined constructor does hide, and thus supersede, the attribute-value constructor for its type if the signature of the user-defined constructor exactly matches the signature of the attribute-value constructor. For the signatures to match, the names and types of the parameters (after the implicit SELF
parameter) of the user-defined constructor must be the same as the names and types of the attributes of the type. The mode of the parameters (after the implicit SELF
parameter) of the user-defined constructor must be IN
.
If an attribute-value constructor is not hidden by a user-defined constructor that has the same name and signature, the attribute-value constructor can still be called.
Note that, if you evolve a type—for example, by adding an attribute—the signature of the attribute-value constructor of the type changes accordingly. This can cause a formerly hidden attribute-value constructor to become usable again.
You call a user-defined constructor like any other function and you can use it anywhere you can use an ordinary Lfunction.
The SELF
argument is passed in implicitly and may not be passed in explicitly. In other words, usages like the following are not allowed:
NEW constructor(instance, argument_list)
A user-defined constructor cannot occur in the DEFAULT
clause of a CREATE
or ALTER
TABLE
statement, but an attribute-value constructor can. The arguments to the attribute-value constructor must not contain references to PL/SQL functions or to other columns, including the pseudocolumns LEVEL
, PRIOR
, and ROWNUM
, or to date constants that are not fully specified. The same is true for check constraint expressions: an attribute-value constructor can be used as part of check constraint expressions while creating or altering a table, but a user-defined constructor cannot.
Parentheses are required in SQL even for constructor calls that have no arguments. In PL/SQL, parentheses are optional when invoking a zero-argument constructor. They do, however, make it more obvious that the constructor call is a function call. The following PL/SQL example omits parentheses in the constructor call to create a new shape:
shape s := NEW my_schema.shape;
The NEW
keyword and the schema name are optional.
Example 8-11 creates a subtype under the type created in Example 8-10 and shows examples for calling the user-defined constructors.
Example 8-11 Calling User-Defined Constructors
-- Requires Ex. 8-10
CREATE TYPE rectangle UNDER shape (
len NUMBER,
wth NUMBER,
CONSTRUCTOR FUNCTION rectangle(SELF IN OUT NOCOPY rectangle,
name VARCHAR2, len NUMBER, wth NUMBER) RETURN SELF as RESULT,
CONSTRUCTOR FUNCTION rectangle(SELF IN OUT NOCOPY rectangle,
name VARCHAR2, side NUMBER) RETURN SELF as RESULT);
/
SHOW ERRORS
CREATE TYPE BODY rectangle IS
CONSTRUCTOR FUNCTION rectangle(SELF IN OUT NOCOPY rectangle,
name VARCHAR2, len NUMBER, wth NUMBER) RETURN SELF AS RESULT IS
BEGIN
SELF.name := name;
SELF.area := len*wth;
SELF.len := len;
SELF.wth := wth;
RETURN ;
END;
CONSTRUCTOR FUNCTION rectangle(SELF IN OUT NOCOPY rectangle,
name VARCHAR2, side NUMBER) RETURN SELF AS RESULT IS
BEGIN
SELF.name := name;
SELF.area := side * side;
SELF.len := side;
SELF.wth := side;
RETURN ;
END;
END;
/
CREATE TABLE shape_table OF shape;
INSERT INTO shape_table VALUES(shape('shape1'));
INSERT INTO shape_table VALUES(shape('shape2', 20));
INSERT INTO shape_table VALUES(rectangle('rectangle', 2, 5));
INSERT INTO shape_table VALUES(rectangle('quadrangle', 12, 3));
INSERT INTO shape_table VALUES(rectangle('square', 12));
The following query selects the rows in the shape_table
:
SELECT VALUE(s) FROM shape_table s;
VALUE(S)(NAME, AREA)
---------------------------------------------
SHAPE('shape1', 0)
SHAPE('shape2', 20)
RECTANGLE('rectangle', 10, 2, 5)
RECTANGLE('quadrangle', 36, 12, 3)
RECTANGLE('square', 144, 12, 12)
The following PL/SQL code calls the constructor:
s shape := NEW shape('void');
A SQLJ object type is a SQL object type mapped to a Java class. A SQLJ object type has an attribute-value constructor. It can also have user-defined constructors that are mapped to constructors in the referenced Java class.
Example 8-12 Creating a SQLJ Object
CREATE TYPE address AS OBJECT EXTERNAL NAME 'university.address' LANGUAGE JAVA USING SQLData( street VARCHAR2(100) EXTERNAL NAME 'street', city VARCHAR2(50) EXTERNAL NAME 'city', state VARCHAR2(50) EXTERNAL NAME 'state', zipcode NUMBER EXTERNAL NAME 'zipcode', CONSTRUCTOR FUNCTION address (SELF IN OUT NOCOPY address, street VARCHAR2, city VARCHAR2, state VARCHAR2, zipcode NUMBER) RETURN SELF AS RESULT AS LANGUAGE JAVA NAME 'university.address (java.lang.String, java.lang.String, java.lang.String, int) return address'); /
A SQLJ type of a serialized representation can have only a user-defined constructor. The internal representation of an object of SQLJ type is opaque to SQL, so an attribute-value constructor is not possible for a SQLJ type.
Oracle database has three special SQL data types that enable you to dynamically encapsulate and access type descriptions, data instances, and sets of data instances of any other SQL type, including object and collection types. You can also use these three special types to create anonymous types, including anonymous collection types.
The three SQL types are implemented as opaque types. In other words, the internal structure of these types is not known to the database; their data can be queried only by implementing functions (typically 3GL routines) for the purpose. Oracle database provides both an OCI and a PL/SQL API for implementing such functions.
The structure of a transient type is opaque to the database. Therefore, they cannot be persistently stored. You cannot create columns of transient types or make them attributes of persistent types.
The three generic SQL types are described in Table 8-2.
Table 8-2 Generic SQL Types
Type | Description |
---|---|
A type description type. A An | |
A self-describing data instance type. A The following cannot be stored in an
| |
A self-describing data set type. A The following cannot be stored in an
|
Each of these three types can be used with any built-in type native to the database as well as with object types and collection types, both named and unnamed. The types provide a generic way to work dynamically with type descriptions, lone instances, and sets of instances of other types. Using the APIs, you can create a transient ANYTYPE
description of any kind of type. Similarly, you can create or convert (cast) a data value of any SQL type to an ANYDATA
and can convert an ANYDATA
(back) to a SQL type. And similarly again with sets of values and ANYDATASET
.
The generic types simplify working with stored procedures. You can use the generic types to encapsulate descriptions and data of standard types and pass the encapsulated information into parameters of the generic types. In the body of the procedure, you can detail how to handle the encapsulated data and type descriptions of whatever type.
You can also store encapsulated data of a variety of underlying types in one table column of type ANYDATA
or ANYDATASET
. For example, you can use ANYDATA
with Advanced Queuing to model queues of heterogeneous types of data. You can query the data of the underlying data types like any other data.
Example 8-13 defines and executes a PL/SQL procedure that uses methods built into SYS.ANYDATA
to access information about data stored in a SYS.ANYDATA
table column.
Example 8-13 Using SYS.ANYDATA
CREATE OR REPLACE TYPE dogowner AS OBJECT ( ownerno NUMBER, ownername VARCHAR2(10) ); / CREATE OR REPLACE TYPE dog AS OBJECT ( breed VARCHAR2(10), dogname VARCHAR2(10) ); / CREATE TABLE mytab ( id NUMBER, data SYS.ANYDATA ); INSERT INTO mytab VALUES ( 1, SYS.ANYDATA.ConvertNumber (5) ); INSERT INTO mytab VALUES ( 2, SYS.ANYDATA.ConvertObject ( dogowner ( 5555, 'John') ) ); commit; CREATE OR REPLACE procedure P IS CURSOR cur IS SELECT id, data FROM mytab; v_id mytab.id%TYPE; v_data mytab.data%TYPE; v_type SYS.ANYTYPE; v_typecode PLS_INTEGER; v_typename VARCHAR2(60); v_dummy PLS_INTEGER; v_n NUMBER; v_dogowner dogowner; non_null_anytype_for_NUMBER exception; unknown_typename exception; BEGIN OPEN cur; LOOP FETCH cur INTO v_id, v_data; EXIT WHEN cur%NOTFOUND; v_typecode := v_data.GetType ( v_type /* OUT */ ); CASE v_typecode WHEN Dbms_Types.Typecode_NUMBER THEN IF v_type IS NOT NULL THEN RAISE non_null_anytype_for_NUMBER; END IF; v_dummy := v_data.GetNUMBER ( v_n /* OUT */ ); Dbms_Output.Put_Line ( To_Char(v_id) || ': NUMBER = ' || To_Char(v_n) ); WHEN Dbms_Types.Typecode_Object THEN v_typename := v_data.GetTypeName(); IF v_typename NOT IN ( 'HR.DOGOWNER' ) THEN RAISE unknown_typename; END IF; v_dummy := v_data.GetObject ( v_dogowner /* OUT */ ); Dbms_Output.Put_Line ( To_Char(v_id) || ': user-defined type = ' || v_typename || '(' || v_dogowner.ownerno || ', ' || v_dogowner.ownername || ' )' ); END CASE; END LOOP; CLOSE cur; EXCEPTION WHEN non_null_anytype_for_NUMBER THEN RAISE_Application_Error ( -20000, 'Paradox: the return AnyType instance FROM GetType ' || 'should be NULL for all but user-defined types' ); WHEN unknown_typename THEN RAISE_Application_Error ( -20000, 'Unknown user-defined type ' || v_typename || ' - program written to handle only HR.DOGOWNER' ); END; / SELECT t.data.gettypename() FROM mytab t; SET SERVEROUTPUT ON; EXEC P;
The query and the procedure P in the preceding code sample produce output like the following:
T.DATA.GETTYPENAME()
-------------------------------------------------------------
SYS.NUMBER
HR.DOGOWNER
1: NUMBER = 5
2: user-defined type = HR.DOGOWNER(5555, John )
Corresponding to the three generic SQL types are three OCI types that model them. Each has a set of functions for creating and accessing the respective type:
OCIType
: corresponds to SYS.ANYTYPE
OCIAnyData
: corresponds to SYS.ANYDATA
OCIAnyDataSet
: corresponds to SYS.ANYDATASET
See Also:
|
Oracle database provides a number of pre-defined aggregate functions such as MAX
, MIN
, SUM
for performing operations on a set of records. These pre-defined aggregate functions can be used only with scalar data. However, you can create your own custom implementations of these functions, or define entirely new aggregate functions, to use with complex data—for example, with multimedia data stored using object types, opaque types, and LOBs.
User-defined aggregate functions are used in SQL DML statements just like the Oracle database built-in aggregates. Once such functions are registered with the server, the database simply invokes the aggregation routines that you supplied instead of the native ones.
User-defined aggregates can be used with scalar data as well. For example, it may be worthwhile to implement special aggregate functions for working with complex statistical data associated with financial or scientific applications.
User-defined aggregates are a feature of the Extensibility Framework. You implement them using ODCIAggregate
interface routines.
See Also: Oracle Database Data Cartridge Developer's Guide for information on using theODCIAggregate interface routines to implement user-defined aggregate functions |
You can use nested table locators to improve performance when retrieving data.
Collection types do not map directly to a native type or structure in languages such as C++ and Java. An application using those languages must access the contents of a collection through Oracle database interfaces, such as OCI.
Generally, when the client accesses a nested table explicitly or implicitly (by fetching the containing object), the database returns the entire collection value to the client process. For performance reasons, a client may wish to delay or avoid retrieving the entire contents of the collection. Oracle database handles this case for you by using a locator instead of the actual nested table value. When you really access the contents of the collection, they are automatically transferred to the client.
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. Because 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.
atomically null object
An object whose value is NULL
is called atomically null. An atomically null object is different from an object that has null values for all its attributes.
character large object (CLOB)
The large object (LOB) data type whose value is composed of character data corresponding to the database character set.
column object
An object that is stored as a column of a relational database table (as opposed to an object table). A column object can also be an attribute of another object. A column object is also known as a stored inline object or an embedded object.
dynamic method dispatch
A method call that is dispatched at run-time to the nearest method implementation when there are multiple implementations of the same method using overriding.
literal invocation
An invocation where all arguments are literals or invocations of literal methods. Arguments cannot be variables.
multilevel collection type
Ccollection types whose elements are collection types, either directly or indirectly.
multiset operators
An operator that combines elements of two nested tables into a single nested table.
object identifier
Identifier for a row object which can be either system-generated (default) or based on a primary key using the CREATE
TABLE
statement.
object type
The type of the object instance. It is similar to a record that has methods. Object types are user-defined.
polymorphism
Allows handling data types and methods generically using the same interface. In polymorphic overriding, subtypes redefine a method they have inherited. In polymorphic overloading, there may be several versions of the same method, with different parameters.
REF
An Oracle built-in data type that encapsulates references to row objects of a specified object type.
specializing
Adding new attributes or methods to a subtype that the parent supertype does not have, or changing the implementation of a method or methods.
stored procedure
A PL/SQL block that is stored in the database and can be executed from an application.
substitutability
A supertype is substitutable if one of its subtypes can substitute or stand in for it in a variable or column whose declared type is the supertype.
Oracle Database Object-Relational Developer's Guide explains how to use the object-relational features of the Oracle Database, 11g release 1 (11.1). Information in this guide applies to versions of the Oracle Database that run on all platforms, and does not include system-specific information.
Oracle Database Object-Relational Developer's Guide is intended for programmers developing new applications or converting existing applications to run in the Oracle environment. The object-relational features are often used in content management, data warehousing, data/information integration, and similar applications that deal with complex structured data. The object views feature can be valuable when writing new C++, C#, Java, or XML applications on top of an existing relational schema.
This guide assumes that you have a working knowledge of application programming and that you are familiar with the use of Structured Query Language (SQL) to access information in relational databases. You should be familiar with the information in Oracle Database SQL Quick Reference, Oracle Database PL/SQL Language Reference, and Oracle Database 2 Day Developer's Guide, and with object-oriented programming techniques.
For information about Oracle's commitment to accessibility, visit the Oracle Accessibility Program website at http://www.oracle.com/us/corporate/accessibility/index.html
.
Access to Oracle Support
Oracle customers have access to electronic support through My Oracle Support. For information, visit http://www.oracle.com/support/contact.html
or visit http://www.oracle.com/accessibility/support.html
if you are hearing impaired.
For more information, see these Oracle resources:
Oracle Database Concepts for information about basic Oracle concepts
Oracle Database SQL Language Reference and Oracle Database Administrator's Guide for information about SQL
Oracle Database PL/SQL Language Reference for information about PL/SQL, the procedural language extension to Oracle SQL
Oracle Database Advanced Application Developer's Guide for general information about developing applications
Oracle Database JDBC Developer's Guide and Reference and Oracle Database Java Developer's Guide for information about Oracle object-relational features through Java
Oracle Call Interface Programmer's Guide and Oracle C++ Call Interface Programmer's Guide for information about using the Oracle Call Interface (OCI) and Oracle C++ Call Interface (OCCI) to build third-generation language (3GL) applications that interact with one or more the Oracle databases
Pro*C/C++ Programmer's Guide for information about Oracle's Pro* series of precompilers, which allow you to embed SQL and PL/SQL in 3GL application programs written in Ada, C, C++, COBOL, or FORTRAN
Oracle XML DB Developer's Guide and Oracle XML Developer's Kit Programmer's Guide for information about developing applications with XML
Oracle Database SecureFiles and Large Objects Developer's Guide for information about Large Objects (LOBs)
Oracle Developer Tools for Visual Studio Help
Many of the examples in this book use the sample schemas, which are installed by default when you select the Basic Installation option with an Oracle Database installation. Refer to Oracle Database Sample Schemas for information on how these schemas were created and how you can use them yourself.
To download free release notes, installation documentation, white papers, or other collateral, please visit the Oracle Technology Network (OTN). You must register online before using OTN; registration is free and can be done at
http://www.oracle.com/technology/contact/welcome.html
If you already have a username and password for OTN, then you can go directly to the documentation section of the OTN Web site at
http://www.oracle.com/technology/documentation/index.html
The following text conventions are used in this document:
Convention | Meaning |
---|---|
boldface | Boldface type indicates graphical user interface elements associated with an action, or terms defined in text or the glossary. |
italic | Italic type indicates book titles, emphasis, or placeholder variables for which you supply particular values. |
monospace | Monospace type indicates commands within a paragraph, URLs, code in examples, text that appears on the screen, or text that you enter. |
This chapter explains how Oracle objects work in combination with the rest of the database, and how to perform DML and DDL operations on them. It contains the following major sections:
Privileges for object types exist at the system level and the schema object level.
This section contains the following topics:
Oracle database defines the following system privileges for object types:
CREATE
TYPE
enables you to create object types in your own schema
CREATE
ANY
TYPE
enables you to create object types in any schema
ALTER
ANY
TYPE
enables you to alter object types in any schema
DROP
ANY
TYPE
enables you to drop named types in any schema
EXECUTE
ANY
TYPE
enables you to use and reference named types in any schema
UNDER
ANY
TYPE
enables you to create subtypes under any non-final object types
UNDER
ANY
VIEW
enables you to create subviews under any object view
The following roles are helpful:
The RESOURCE
role includes the CREATE
TYPE
system privilege.
The DBA role includes all of these privileges.
Two schema object privileges apply to object types:
EXECUTE
enables you to use the type to:
Define a table.
Define a column in a relational table.
Declare a variable or parameter of the named type.
EXECUTE
lets you invoke the methods of a type, including the constructor.
Method execution and the associated permissions are the same as for stored PL/SQL procedures.
UNDER
enables you to create a subtype or subview under the type or view on which the privilege is granted.
Only a grantor with the UNDER
privilege WITH
GRANT
OPTION
on the direct supertype or superview can grant the UNDER
privilege on a subtype or subview.
The phrase WITH
HIERARCHY
OPTION
grants a specified object privilege on all subtypes of the object. This option is meaningful only with the SELECT
object privilege granted on an object view in an object view hierarchy. In this case, the privilege applies to all subviews of the view on which the privilege is granted.
In addition to the permissions detailed in the previous sections, you need specific privileges to:
Create types or tables that use types created by other users.
Grant use of your new types or tables to other users.
You must have either the EXECUTE
ANY
TYPE
system privilege or the EXECUTE
object privilege for any type used to define a new type or table. You must have been granted these privileges explicitly, and not through a role.
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 been granted these privileges explicitly, not through a role.
Example 7-1 creates three users or schemas, USER1
, USER2
, and USER3
, and grants them the CREATE
SESSION
and RESOURCE
roles. Some of the subsequent examples in this chapter use these schemas.
This example requires you to create and use several passwords. If you plan to run the example, make these changes to your SQL code first.
Note: For simplicity, this example does not perform the password management techniques that a deployed system normally uses. In a production environment, follow the Oracle Database password management guidelines, and disable any sample accounts. See Oracle Database Security Guide for password management guidelines and other security recommendations. |
Example 7-1 Creating User Schemas
-- Requires passwords
CONNECT SYSTEM
-- Enter password
CREATE USER user1 PROFILE default
IDENTIFIED BY password DEFAULT TABLESPACE example ACCOUNT UNLOCK;
GRANT CREATE SESSION TO user1;
GRANT RESOURCE TO user1;
GRANT CREATE SYNONYM TO user1;
GRANT CREATE PUBLIC SYNONYM TO user1;
GRANT DROP PUBLIC SYNONYM TO user1;
CREATE USER user2 PROFILE default
IDENTIFIED BY password DEFAULT TABLESPACE example ACCOUNT UNLOCK;
GRANT CREATE SESSION TO user2;
GRANT RESOURCE TO user2;
CREATE USER user3 PROFILE default
IDENTIFIED BY password DEFAULT TABLESPACE example ACCOUNT UNLOCK;
GRANT CREATE SESSION TO user3;
GRANT RESOURCE TO user3;
Example 7-2 requires the input of a password, USER1
performs the CREATE
and GRANT
Data Definition Language (DDL) statements in the USER1
schema:
Example 7-2 Granting Privileges on Object Types
-- Requires Ex. 7-1 and the input of a password
CONNECT user1
-- Enter password
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;
In Example 7-3, USER2
performs the CREATE
DDL statement in the USER2
schema:
Example 7-3 Performing DDL Statements in USER2 Schema
-- Requires Ex. 7-1, 7-2 and password input CONNECT user2 -- Enter password CREATE TABLE tab1 OF user1.type1; CREATE TYPE type3 AS OBJECT ( attr3 user1.type2 ); / CREATE TABLE tab2 (col1 user1.type2 );
In Example 7-4, the first two statements succeed because USER2
was granted the EXECUTE
privilege with the GRANT
option on USER1
's TYPE2
in the last line of Example 7-2 and Example 7-3 created type3
as an object using attr3
user1.type2
.
However, the last grant Example 7-4 fails because USER2
has not been granted the EXECUTE
privilege with the GRANT
option on USER1.TYPE1
.
Example 7-4 Performing Grants to USER3
-- Requires Ex. 7-1, 7-2, and 7-3 GRANT EXECUTE ON type3 TO user3; GRANT SELECT ON tab2 TO user3; -- Privileges on Object Types GRANT SELECT ON tab1 TO user3 -- incorrect statement;
In Example 7-5, USER3
has the necessary privileges to perform the following actions:
Object types only make use of the EXECUTE
privilege, but object tables use all the same privileges as relational tables:
SELECT
lets you access an object and its attributes from the table.
UPDATE
lets you modify attributes of objects in the table.
INSERT
lets you add new objects to the table.
DELETE
lets you delete objects from the table.
Similar table and column privileges regulate the use of table columns of object 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 and queries in Example 7-6:
Example 7-6 SELECT Privileges on Type Access
-- Requires Ex. 7-1, 7-2, 7-3, 7-4, and 7-5 CREATE TYPE emp_type AS OBJECT ( eno NUMBER, ename VARCHAR2(36)); / CREATE TABLE emp OF emp_type; // an object table GRANT SELECT on emp TO user1; SELECT VALUE(e) FROM emp e; SELECT eno, ename FROM emp;
For both queries, Oracle database checks the user's SELECT
privilege for the object table emp
. 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, the database checks the user's EXECUTE
privilege.
The second query, however, does not involve named types, so the database does not check type privileges.
Additionally, USER3
can perform queries such as these:
SELECT t.col1.attr2 from user2.tab2 t; SELECT t.attr4.attr3.attr2 FROM tab3 t;
Note that in both queries, USER3
does not have explicit privileges on the underlying type. However, the statement succeeds because the type and table owners have the necessary privileges with the GRANT
option.
Oracle database checks privileges on the following requests and returns an error if the requestor does not have the privilege for the action:
Pinning an object in the object cache using its REF
value causes the database to check the SELECT
privilege on the object table containing the object and the EXECUTE
privilege on the object type.
See Also: Oracle Call Interface Programmer's Guide for tips and techniques for using OCI program effectively with objects |
Modifying an existing object or flushing an object from the object cache causes the database to check the UPDATE
privilege on the destination object table. Flushing a new object causes the database to check the INSERT
privilege on the destination object table.
Deleting an object causes the database to check the DELETE
privilege on the destination table.
Invoking a method causes the database to check the EXECUTE
privilege on the corresponding object type.
Oracle database does not provide column level privileges for object tables.
This section discusses type dependencies in two broad categories:
Situations where types depend upon each other for their definitions, where one type might be part of the definition of another type.
Situations where creating or dropping types is complicated by dependencies that the type has such, as tables or types.
This section covers the following topics:
Types that depend on each other for their definitions, either directly or through intermediate types, are called mutually dependent. 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.
If you visualize a diagram with arrows showing the relationships among a set of mutually dependent types, the connections form a loop. To define such a circular dependency, you must use REF
s for at least one segment of the circle.
For example, you can define the types show in Example 7-7.
Example 7-7 Creating Dependent Object Types
-- Requires Ex. 7-1 and password CONNECT user1 -- Enter password ALTER SESSION SET PLSQL_WARNINGS = 'enable:all'; CREATE TYPE department; // a placeholder / 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 database compiles it without errors.
Notice that the code in Example 7-7 creates the type department
twice. The first statement is an optional, incomplete declaration of department
that serves as a placeholder for the REF
attribute of employee
to point to. The declaration is incomplete in that it omits the AS
OBJECT
phrase and lists no attributes or methods. These are specified later in the full declaration that completes the type. In the meantime, department
is created as an incomplete object type. This enables the compilation of employee
to proceed without errors.
If you do not create incomplete types as placeholders, types that refer to the missing types still compile, but the compilation proceeds with errors. For example, if department
did not exist at all, Oracle database would create it as an incomplete type and compile employee
with errors. Then employee
would be recompiled the next time that some operation accesses it. This time, if all the types it depends on have been created and its dependencies are satisfied, it compiles without errors.
Incomplete types also enable you to create types that contain REF
attributes to a subtype that has not yet been created. To create such a supertype, first create an incomplete type of the subtype to be referenced. Create the complete subtype after you create the supertype.
When you have created all the types referenced by an incomplete type, complete the declaration of the incomplete type, because there is no longer any need for it to remain incomplete. Completing the type recompiles it and enables the system to release various locks.
To complete an incomplete type, you execute a CREATE
TYPE
statement that specifies the attributes and methods of the type, as shown at the end of Example 7-7.
Also, you must complete any incomplete types that the database creates for you. If, as discussed in the preceding section, you did not explicitly create department
as an incomplete type, then the database did. In this case, you still need to complete it.
You must complete an incomplete object type as an object type: you cannot complete an object type as a collection type (a nested table type or an array type). The only alternative is to drop the type.
If a type was created with compilation errors, and you attempt an operation on it, such as creating tables or inserting rows, you may receive an error. You need to recompile the type before attempting the operation. To manually recompile a type, execute an ALTER
TYPE
typename
COMPILE
statement. After you have successfully compiled the type, attempt the operation again.
The CREATE
OR
REPLACE
TYPE
statement throws an error if the type being replaced has table or type dependencies. This applies to objects, varrays, and nested table types. This also applies to type dependencies involving either inheritance or type composition (embedding one type into another). The latter might be a situation where one type is attribute of another.
Using the FORCE
option with a CREATE
OR
REPLACE
TYPE
statement enables you to replace a type if it has type dependencies, but not table dependencies. Table dependencies still cause errors.
Example 7-8 shows a CREATE
OR
REPLACE
statement (second statement) that fails due to a type dependency.
Example 7-8 CREATE OR REPLACE Type and Table Failure
SQL> CREATE type t1 AS OBJECT (a number) not final;
2 /
Type created.
SQL> CREATE TYPE t2 UNDER t1 (b varchar(10));
2 /
Type created.
SQL> CREATE OR REPLACE TYPE t1 AS OBJECT (c varchar(20));
2 /
CREATE OR REPLACE TYPE t1 AS OBJECT (c varchar(20));
*
ERROR at line 1:
ORA-02303: cannot drop or replace a type with type or table dependents
Example 7-9 shows code in which a CREATE
OR
REPLACE
FORCE
statement succeeds in replacing a type that has a type dependency and then creates a table using the parent type. However, the final CREATE
OR
REPLACE
FORCE
statement fails because the type now has a table dependency and even with the FORCE
option, a type with a table dependency cannot be replaced.
Example 7-9 CREATE OR REPLACE with FORCE
SQL> CREATE OR REPLACE TYPE t1 FORCE AS OBJECT (c varchar(20));
2 /
Type created.
SQL> CREATE TABLE tb1 (c1 t1);
Table created.
SQL> CREATE OR REPLACE TYPE t1 FORCE AS OBJECT (d number);
2 /
CREATE OR REPLACE TYPE
t1 FORCE AS OBJECT (d number);
*
ERROR at line 1:
ORA-22866: cannot replace a type with table dependents
See Also: Oracle Database PL/SQL Language Reference for details of theCREATE OR REPLACE TYPE SQL statement |
A substitutable table or column of a specific type is dependent not only on that type but on all subtypes of the type as well. This is because a hidden column is added to the table for each attribute added in a subtype of the type. The hidden columns are added even if the substitutable table or column contains no data of that subtype.
In Example 7-10, a persons
table of type person_typ
is dependent not only on person_typ
but also on the person_typ
subtypes student_typ
and part_time_student_typ
.
If you attempt to drop a subtype that has a dependent type, table, or column, the DROP
TYPE
statement returns an error and aborts. Consequently, trying to drop a part_time_student_typ
raises an error because of the dependent persons
table.
If dependent tables or columns exist but contain no data of the type being dropped, you can use the VALIDATE
keyword to drop the type. The VALIDATE
keyword causes Oracle database to check for actual stored instances of the specified type and to drop the type if none are found. This also removes hidden columns associated with attributes unique to the type.
In Example 7-10, the first DROP
TYPE
statement fails because part_time_student_typ
has a dependent table (persons
). But if persons
contains no instances of part_time_student_typ
(nor does any other dependent table or column), the VALIDATE
keyword causes the second DROP
TYPE
statement to succeed.
Example 7-10 DROP TYPE with and without VALIDATE
CREATE TYPE person_typ AS OBJECT ( idno NUMBER, name VARCHAR2(30), phone VARCHAR2(20)) NOT FINAL; / CREATE TYPE student_typ UNDER person_typ ( dept_id NUMBER, major VARCHAR2(30)) NOT FINAL; / CREATE TYPE part_time_student_typ UNDER student_typ (number_hours NUMBER); / CREATE TABLE persons OF person_typ; -- Following generates an error due to presence of Persons table DROP TYPE part_time_student_typ -- incorrect statement; -- Following succeeds if there are no stored instances of part_time_student_typ DROP TYPE part_time_student_typ VALIDATE;
Note: Oracle recommends that you always use theVALIDATE option while dropping subtypes. |
The DROP
TYPE
statement also has a FORCE
option that causes the type to be dropped even though it may have dependent types or tables. Use the FORCE
option with great care, because any dependent types or tables that do exist are marked invalid and become inaccessible when the type is dropped. Data in a table that is marked invalid for this reason can never be accessed again. The only action that can be performed on such a table is to drop it.
See "Type Evolution" for information about how to alter a type.
Just as you can create synonyms for tables, views, and various other schema objects, you can also define synonyms for object types.
Synonyms for types have the same advantages as synonyms for other kinds of schema objects: they provide a location-independent way to reference the underlying schema object. An application that uses public type synonyms can be deployed unaltered, in any schema of a database, without requiring a qualified type name with the schema name.
This section contains the following topics:
You create a type synonym with a CREATE
SYNONYM
statement. The user must have been granted CREATE
SYNONYM
and CREATE
PUBLIC SYNONYM
privileges.
For example, t)#hese statements create a type typ1
and then create a synonym for it:
Example 7-11 CREATE TYPE / SYNONYM for user1
-- Example requires Ex.7-1 which created user1 and granted it the CREATE SYNONYM
-- and CREATE PUBLIC SYNONYM privileges
-- connect as user1 if not already connected.
CREATE TYPE typ1 AS OBJECT (x number);
/
CREATE SYNONYM syn1 FOR typ1;
Synonyms can be created for collection types, too. The following example creates a synonym for a nested table type:
CREATE TYPE typ2 AS TABLE OF NUMBER;
/
CREATE SYNONYM syn2 FOR typ2;
You create a public synonym by using the PUBLIC
keyword:
CREATE TYPE shape AS OBJECT ( name VARCHAR2(10) );
/
CREATE PUBLIC SYNONYM pub_shape FOR shape;
With the REPLACE
option you can make the synonym point to a different underlying type. For example, the following statement causes syn1
to point to type typ2
instead of the type it formerly pointed to:
CREATE OR REPLACE SYNONYM syn1 FOR typ2;
You can use a type synonym anywhere that you can refer to a type. For instance, you can use a type synonym in a DDL statement to name the type of a table column or type attribute.
Example 7-12 uses synonym syn1
to specify the type of an attribute in type typ3
:
Example 7-12 Using a Type Synonym in a Create Statement
-- Requires Ex 7-1 and connection as user1 -- drop syn1 and typ1 if created for Ex. 7-12 CREATE TYPE typ1 AS OBJECT (x number); / CREATE SYNONYM syn1 FOR typ1; CREATE TYPE typ3 AS OBJECT ( a syn1 ); /
In the next statement, the type synonym syn1
calls the constructor of the object type typ1
, for which syn1
is a synonym. The statement returns an object instance of typ1
:
SELECT syn1(0) FROM dual;
In the following, syn2
is a synonym for a nested table type. The synonym replaces the actual type name in a CAST
expression.
SELECT CAST(MULTISET(SELECT eno FROM USER3.EMP) AS syn2) FROM dual;
This code returns the following output:
SQL> -- Type synonym used to call a constructor / nested table
SELECT syn1(0) FROM dual;
SELECT CAST(MULTISET(SELECT eno FROM USER3.EMP) AS syn2) FROM
dual;
SQL> SYN1(0)(X)
----------------------------------------------------------------
TYP1(0)
SQL>
CAST(MULTISET(SELECTENOFROMUSER3.EMP)ASSYN2)
----------------------------------------------------------------
TYP2()
Type synonyms can be used in the following kinds of statements:
DML statements: SELECT
, INSERT
, UPDATE
, DELETE
, FLASHBACK
TABLE
, EXPLAIN
PLAN
, and LOCK
TABLE
DDL statements: AUDIT
, NOAUDIT
, GRANT
, REVOKE
, and COMMENT
If a type or table has been created using type synonyms, the DESCRIBE
command shows the synonyms in place of the types they represent. Similarly, catalog views, which show type names, such as USER_TYPE_ATTRS
, show the type synonym names in their place.
You can query the catalog view USER_SYNONYMS
to find out the underlying type of a type synonym.
See Also: Chapter 2 of Oracle Database Reference for a complete list of the data dictionary catalog views |
A type that directly or indirectly references a synonym in its type declaration is a dependent of that synonym. Thus, in the following line from Example 7-12, type typ3
is a dependent type of synonym syn1
.
CREATE TYPE typ3 AS OBJECT ( a syn1 ); /
Other kinds of schema objects that reference synonyms in their DDL statements also become dependents of those synonyms. An object that depends on a type synonym depends on both the synonym and the underlying type of the synonym.
The dependency relationships of a synonym affect your ability to drop or rename the synonym. Dependent schema objects are also affected by some operations on synonyms. The following sections describe these various ramifications.
You can replace a synonym only if it has no dependent tables or valid user-defined types. Replacing a synonym is equivalent to dropping it and then re-creating a new synonym with the same name.
You drop a synonym with the DROP
SYNONYM
statement as shown in Example 7-13.
You cannot drop a type synonym if it has table or valid object types as dependents unless you use the FORCE
option. The FORCE
option causes any columns that directly or indirectly depend on the synonym to be marked unused, just as if the actual types of the columns were dropped. (A column indirectly depends on a synonym if, for instance, the synonym is used to specify the type of an attribute of the declared type of the column.)
Any dependent schema objects of a dropped synonym are invalidated. They can be revalidated by creating a local object or a new public synonym with the same name as the dropped synonym.
Dropping the underlying base type of a type synonym has the same effect on dependent objects as dropping the synonym.
You can rename a type synonym with the RENAME
statement. Renaming a synonym is equivalent to dropping it and then re-creating it with a new name. You cannot rename a type synonym if it has dependent tables or valid object types. The following example fails because synonym syn1
has a dependent object type:
RENAME syn1 TO syn3 -- invalid statement;
You cannot create a local schema object that has the same name as a public synonym if the public synonym has a dependent table or valid object type in the local schema that will hold the new schema object. Nor can you create a local schema object that has the same name as a private synonym in the same schema.
For instance, in the following example, table shape_tab
is a dependent table of public synonym pub_shape
because the table has a column that uses the synonym in its type definition. Consequently, the attempt to create a table that has the same name as public synonym pub_shape
, in the same schema as the dependent table, fails:
-- Following uses public synonym pub_shape CREATE TABLE shape_tab ( c1 pub_shape ); -- Following is not allowed CREATE TABLE pub_shape ( c1 NUMBER ) -- invalid statement;
When tuning objects, the following items need to be addressed:
How objects and object views consume CPU and memory resources during runtime
How to monitor memory and CPU resources during runtime
How to manage large numbers of objects
Some of the key performance factors are the following:
DBMS_STATS
package to collect statistics
tkprof
to profile execution of SQL commands
EXPLAIN
PLAN
to generate the query plans
See Also: Oracle Database Performance Tuning Guide for details on measuring and tuning the performance of your application |