Oracle8i Application Developer's Guide - Fundamentals Release 8.1.5 A68003-01 |
|
This chapter has an extended example of how to use user-defined datatypes (Oracle objects). The example shows how a relational model might be transformed into an object-relational model that better represents the real-world entities that are managed by an application.
This chapter contains the following sections:
User-defined types are schema objects in which users formalize the data structures and operations that appear in their applications.
See Also: Oracle8i Concepts for an introduction to user-defined types and instructions on how to use them. |
The example in this chapter illustrates the most important aspects of defining and using user-defined types. One important aspect of using user-defined types is creating methods that perform operations on objects. In the example, definitions of object type methods use the PL/SQL language. Other aspects of using user-defined types, such as defining a type, use SQL.
See Also: Oracle8i SQL Reference for a complete description of SQL syntax and usage for user-defined types. |
PL/SQL and Java provide additional capabilities beyond those illustrated in this chapter, especially in the area of accessing and manipulating the elements of collections.
See Also: PL/SQL User's Guide and Reference for a complete discussion of PL/SQL capabilities, and Oracle8i Java Stored Procedures Developer's Guide for a complete discussion of Java. |
Client applications that use the Oracle Call Interface (OCI), Pro*C/C++, or Oracle Objects for OLE (OO4O) can take advantage of its extensive facilities for accessing objects and collections, and manipulating them on clients.
See Also: Oracle Call Interface Programmer's Guide, Pro*C/C++ Precompiler Programmer's Guideo and Oracle Objects for OLE/ActiveX Programmer's Guide for more information. |
This example is based on a simple business activity: managing customer orders. The hypothetical application is presented utilizing three different approaches.
The basic entities in this example are:
As you can see from Figure 16-1, a customer has contact information, so that the address and set of telephone numbers is exclusive to that customer. In other words, the application does not allow for different customers to be associated with the same address or telephone numbers. Also, if a customer changes her address, then the previous address ceases to exist; or, if someone ceases to be a customer, then the associated address disappears.
A customer has a one-to-many relationship with a purchase order, because a customer can place many orders, but a given purchase order is placed by a single customer. However, the relationship is optional rather than mandatory, because a person or company be defined as a customer before placing an order.
A purchase order has a many-to-many relationship with a stock item, because a purchase order can contain many stock items, and a stock item can appear on many purchase orders. Because this relationship does not show which stock items appear on which purchase orders, the entity-relationship has the notion of a line item. As pictured in the diagram, a purchase order must contain one or more line items. Each line item is associated only with a single purchase order.
The relationship between line item and stock item is that a particular stock item can appear on none or many line items, but each line item must refer to one and only one stock item.
The relational approach normalizes entities and their attributes, and structures customers, purchase orders, and stock item into tables. The table names are Customer_reltab
, PurchaseOrder_reltab
, and Stock_reltab
.
Taking the relational approach means breaking addresses into their standard parts and allocating these to columns in the Customer_reltab
table. A side-effect of structuring telephone numbers as columns is that doing so sets an arbitrary limit on the number of telephone numbers a customer can have.
The relational approach separates line items from their purchase orders and puts each into its own table, named PurchaseOrder_reltab
and LineItems_reltab
. As depicted in Figure 16-1, a line item has a relationship to both a purchase order and a stock item. Under the relational model, these are implemented as columns in LineItems_reltab
table with foreign keys to PurchaseOrder_reltab
and Stock_reltab
.
The relational approach results in the following tables:
The Customer_reltab
table has the following definition:
CREATE TABLE Customer_reltab ( CustNo NUMBER NOT NULL, CustName VARCHAR2(200) NOT NULL, Street VARCHAR2(200) NOT NULL, City VARCHAR2(200) NOT NULL, State CHAR(2) NOT NULL, Zip VARCHAR2(20) NOT NULL, Phone1 VARCHAR2(20), Phone2 VARCHAR2(20), Phone3 VARCHAR2(20), PRIMARY KEY (CustNo) ) ;
This table, Customer_reltab
, stores all the information about customers, which means that it fully contains information that is intrinsic to the customer (defined with the NOT
NULL
constraint) and information that is not as essential. According to this definition of the table, the application requires that every customer have a shipping address.
Our Entity-Relationship (E-R) diagram showed a customer placing an order, but the table does not make allowance for any relationship between the customer and the purchase order. This suggests that the relationship must be managed by the purchase order.
The PurchaseOrder_reltab
table has the following definition:
CREATE TABLE PurchaseOrder_reltab ( PONo NUMBER, /* purchase order no */ Custno NUMBER references Customer_reltab, /* Foreign KEY referencing customer */ OrderDate DATE, /* date of order */ ShipDate DATE, /* date to be shipped */ ToStreet VARCHAR2(200), /* shipto address */ ToCity VARCHAR2(200), ToState CHAR(2), ToZip VARCHAR2(20), PRIMARY KEY(PONo) ) ;
As expected, PurchaseOrder_reltab
manages the relationship between the customer and the purchase order by means of the foreign key (FK) column CustNo
, which references the CustNo
key of the PurchaseOrder_reltab
. Because the table makes no allowance for the relationship between the purchase order and its line items, the list of line items must handle this.
The LineItems_reltab
table has the following definition:
CREATE TABLE LineItems_reltab ( LineItemNo NUMBER, PONo NUMBER REFERENCES PurchaseOrder_reltab, StockNo NUMBER REFERENCES Stock_reltab, Quantity NUMBER, Discount NUMBER, PRIMARY KEY (PONo, LineItemNo) ) ;
Note:
The |
The table name is in the plural form LineItems_reltab
as opposed to the singular LineItems_reltab
to emphasize that the table will serve as a collection of line items. Of course, the table name has no effect on the behavior of the table, but it is a useful naming convention because it helps you keep in mind that, while every table is a collection, this is not the same as requiring a table to serve as a collection.
As shown in the E-R diagram, the list of line items has relationships with both the purchase order and the stock item. These relationships are managed by LineItems_reltab
by means of two FK columns:
PONo
, which references the PONo
column in PurchaseOrder_reltab
StockNo
, which references the StockNo
column in Stock_reltab
The Stock_reltab
table has the following definition:
CREATE TABLE Stock_reltab ( StockNo NUMBER PRIMARY KEY, Price NUMBER, TaxRate NUMBER ) ;
The following drawing is a graphical representation of the relationships between the tables. It is similar to the E-R diagram (Figure 16-1) because it tries to describe the model for the total application. It differs from the E-R diagram because it pictures an implementation of the first approach we are considering -- the relational approach.
In an application based on the tables defined in the previous section, statements similar to the following insert data into the tables.
INSERT INTO Stock_reltab VALUES(1004, 6750.00, 2) ; INSERT INTO Stock_reltab VALUES(1011, 4500.23, 2) ; INSERT INTO Stock_reltab VALUES(1534, 2234.00, 2) ; INSERT INTO Stock_reltab VALUES(1535, 3456.23, 2) ;
INSERT INTO Customer_reltab VALUES (1, 'Jean Nance', '2 Avocet Drive', 'Redwood Shores', 'CA', '95054', '415-555-1212', NULL, NULL) ; INSERT INTO Customer_reltab VALUES (2, 'John Nike', '323 College Drive', 'Edison', 'NJ', '08820', '609-555-1212', '201-555-1212', NULL) ;
INSERT INTO PurchaseOrder_reltab VALUES (1001, 1, SYSDATE, '10-MAY-1997', NULL, NULL, NULL, NULL) ; INSERT INTO PurchaseOrder_reltab VALUES (2001, 2, SYSDATE, '20-MAY-1997', '55 Madison Ave', 'Madison', 'WI', '53715') ;
INSERT INTO LineItems_reltab VALUES(01, 1001, 1534, 12, 0) ; INSERT INTO LineItems_reltab VALUES(02, 1001, 1535, 10, 10) ; INSERT INTO LineItems_reltab VALUES(01, 2001, 1004, 1, 0) ; INSERT INTO LineItems_reltab VALUES(02, 2001, 1011, 2, 1) ;
Assuming that values have been inserted into these tables in the usual way, your application could execute queries similar to the following to retrieve the necessary information from the stored data.
SELECT C.CustNo, C.CustName, C.Street, C.City, C.State, C.Zip, C.phone1, C.phone2, C.phone3, P.PONo, P.OrderDate, L.StockNo, L.LineItemNo, L.Quantity, L.Discount FROM Customer_reltab C, PurchaseOrder_reltab P, LineItems_reltab L WHERE C.CustNo = P.CustNo AND P.PONo = L.PONo AND P.PONo = 1001 ;
SELECT P.PONo, SUM(S.Price * L.Quantity) FROM PurchaseOrder_reltab P, LineItems_reltab L, Stock_reltab S WHERE P.PONo = L.PONo AND L.StockNo = S.StockNo GROUP BY P.PONo ;
SELECT P.PONo, P.CustNo, L.StockNo, L.LineItemNo, L.Quantity, L.Discount FROM PurchaseOrder_reltab P, LineItems_reltab L WHERE P.PONo = L.PONo AND L.StockNo = 1004 ;
Given the schema objects described above, you could execute statements similar to the following to update the stored data:
UPDATE LineItems_reltab SET Quantity = 20 WHERE PONo = 1001 AND StockNo = 1534 ;
In an application based on the tables defined earlier, you could execute statements similar to the following to delete stored data:
DELETE FROM LineItems_reltab WHERE PONo = 1001 ; DELETE FROM PurchaseOrder_reltab WHERE PONo = 1001 ;
The Relational Database Management System (RDBMS) is a very powerful and efficient form of information management. Why then should you even consider another approach? If you examine the application as developed under the relational model in comparison to the real world of the application domain, then certain shortcomings become evident.
Database tables are excellent for modeling a structure of relationships, but they fail to capture the way that objects in the real world are naturally bundled with operations on the data. For example, when you operate on a purchase order in the real world, you expect to be able to sum the line items to find the total cost to the customer. Similarly, you expect that you should be able to retrieve information about the customer who placed the order -- such as name, reference number, address, and so on. More complexly, you may want to determine the customer's buying history and payment pattern.
An RDBMS provides very sophisticated structures for storing and retrieving data, but each application developer must craft the operations needed for each application. This means that you must recode operations often, even though they may be very similar to operations already coded for applications within the same enterprise.
Relational tables do not capture compositions. For example, an address may be a composite of number, street, city, state, and zip code, but in a relational table, the notion of an address as a structure composed of the individual columns is not captured.
Relational tables have difficulty dealing with complex part-whole relationships. A piston and an engine have the same status as columns in the Stock_reltab
, but there is no easy way to describe the fact that pistons are part of engines, except by creating multiple tables with primary key-foreign key relationships. Similarly, there is no easy way to implement the complex interrelationships between collections.
There is no easy way to capture the relationship of generalization-specification (inheritance). If we abstract the base requirements of a purchase order and build a complex technology to capture the relationships, then there is no way to develop purchase orders that use this basic functionality and then further specialize the functionality for different domains. Instead, we will have built the base functionality into every implementation of a purchase order.
So why not create applications using a third-generation language (3GL)?
First, an RDBMS provides functionality that would take millions of person-hours to replicate.
Second, one of the problems of information management using 3GLs is that they are not persistent; or, if they are persistent, then they sacrifice security to obtain the necessary performance by way of locating the application logic and the data logic in the same address space. Neither trade-off is acceptable to users of an RDBMS, for whom both persistence and security are basic requirements.
This leaves the application developer working under the relational model with the problem of simulating complex types by some form of mapping into SQL. Apart from the many person-hours required, this approach involves serious problems of implementation. You must:
Obviously, there is heavy traffic back and forth between the client address space and that of the server, with the accompanying decrement in performance. And, if client and server are on different machines, then the toll on performance from network roundtrips may be considerable.
Object-relational (O-R) technology solves these problems. This chapter and the following chapter present examples that implement this new functionality.
The O-R approach to the previous relational example begins with the same entity relationships outlined in "Entities and Relationships". However, viewing these from the object-oriented perspective portrayed in the class diagram above allows us to define user-defined types that make it possible to translate more of the real-world structure into the database schema.
Rather than breaking up addresses or the customer's contact phones into unrelated columns in relational tables, the O-R approach defines types to represent them; rather than breaking line items out into a separate table, the O-R approach allows them to stay with their respective purchase orders as nested tables.
In the O-R approach, the main entities -- customers, stock, and purchase orders -- become objects. Object references express the relationships between them. Collection types model their multi-valued attributes.
Given an O-R strategy, there are two approaches to implementation:
The remainder of this chapter develops the O-R schema and shows how to implement it with object tables. Chapter 17, "Objects in Views" implements the same schema with object views.
The following statements set the stage:
CREATE TYPE StockItem_objtyp / CREATE TYPE LineItem_objtyp / CREATE TYPE PurchaseOrder_objtyp /
The preceding three statements define incomplete object types. The incomplete definitions notify Oracle that full definitions are coming later. Oracle allows types that refer to these types to compile successfully. Incomplete type declarations are like forward declarations in C and other programming languages.
The following statement defines an array type:
CREATE TYPE PhoneList_vartyp AS VARRAY(10) OF VARCHAR2(20) /
The preceding statement defines the type PhoneList_vartyp
. Any data unit of type PhoneList_vartyp
is a varray of up to 10 telephone numbers, each represented by a data item of type VARCHAR2
.
A list of phone numbers could occupy a varray or a nested table. In this case, the list is the set of contact phone numbers for a single customer. A varray is a better choice than a nested table for the following reasons:
In general, if ordering and bounds are not important design considerations, then designers can use the following rule of thumb for deciding between varrays and nested tables: If you need to query the collection, then use nested tables; if you intend to retrieve the collection as a whole, then use varrays.
See Also: Chapter 18, "Design Considerations for Oracle Objects" for more information about the design considerations for varrays and nested tables. |
The following statement defines the object type Address_objtyp
to represent addresses:
CREATE TYPE Address_objtyp AS OBJECT ( Street VARCHAR2(200), City VARCHAR2(200), State CHAR(2), Zip VARCHAR2(20) ) /
All of the attributes of an address are character strings, representing the usual parts of a simplified mailing address.
The following statement defines the object type Customer_objtyp
, which uses other user-defined types as building blocks. This object type also has a comparison method.
CREATE TYPE Customer_objtyp AS OBJECT ( CustNo NUMBER, CustName VARCHAR2(200), Address_obj Address_objtyp, PhoneList_var PhoneList_vartyp, ORDER MEMBER FUNCTION compareCustOrders(x IN Customer_objtyp) RETURN INTEGER, PRAGMA RESTRICT_REFERENCES ( compareCustOrders, WNDS, WNPS, RNPS, RNDS) ) /
Instances of the type Customer_objtyp
are objects that represent blocks of information about specific customers. The attributes of a Customer_objtyp
object are a number, a character string, an Address_objtyp
object, and a varray of type PhoneList_vartyp
.
Every Customer_objtyp
object also has an associated order method, one of the two types of comparison methods. Whenever Oracle needs to compare two Customer_objtyp
objects, it invokes the compareCustOrders
method to do so.
Note::
The statement does not include the actual PL/SQL program implementing the method |
The two types of comparison methods are map methods and order methods. This application uses one of each for purposes of illustration.
An ORDER
method must be called for every two objects being compared, whereas a MAP
method is called once per object. In general, when sorting a set of objects, the number of times an ORDER
method is called is more than the number of times a MAP
method would be called.
Because the system can perform scalar value comparisons very efficiently, coupled with the fact that calling a user-defined function is slower than calling a kernel implemented function, sorting objects using the ORDER
method is relatively slow compared to sorting the mapped scalar values (returned by the MAP
function).
See Also:
|
The following statement completes the definition of the incomplete object type LineItem_objtyp
declared at the beginning of this section.
CREATE TYPE LineItem_objtyp AS OBJECT ( LineItemNo NUMBER, Stock_ref REF StockItem_objtyp, Quantity NUMBER, Discount NUMBER ) /
Instances of type LineItem_objtyp
are objects that represent line items. They have three numeric attributes and one REF
attribute. The LineItem_objtyp
models the line item entity and includes an object reference to the corresponding stock object.
The following statement defines the nested table type LineItemList_ntabtyp
:
CREATE TYPE LineItemList_ntabtyp AS TABLE OF LineItem_objtyp /
A data unit of this type is a nested table, each row of which contains an object of type LineItem_objtyp
. A nested table of line items is a better choice to represent the multivalued line item list of a purchase order than a varray of LineItem_objtyp
objects would be, for the following reasons:
The following statement completes the definition of the incomplete object type PurchaseOrder_objtyp
declared at the beginning of this section:
CREATE TYPE PurchaseOrder_objtyp AUTHID CURRENT_USER AS OBJECT ( PONo NUMBER, Cust_ref REF Customer_objtyp, OrderDate DATE, ShipDate DATE, LineItemList_ntab LineItemList_ntabtyp, ShipToAddr_obj Address_objtyp, MAP MEMBER FUNCTION getPONo RETURN NUMBER, PRAGMA RESTRICT_REFERENCES ( getPONo, WNDS, WNPS, RNPS, RNDS), MEMBER FUNCTION sumLineItems RETURN NUMBER, PRAGMA RESTRICT_REFERENCES (sumLineItems, WNDS, WNPS) ) /
The preceding statement defines the object type PurchaseOrder_objtyp
. Instances of this type are objects representing purchase orders. They have six attributes, including a REF
to Customer_objtyp
, an Address_objtyp
object, and a nested table of type LineItemList_ntabtyp
, which is based on type LineItem_objtyp
.
Objects of type PurchaseOrder_objtyp
have two methods: getPONo
and sumLineItems
. One, getPONo
, is a MAP
method, one of the two kinds of comparison methods. A MAP
method returns the relative position of a given record within the order of records within the object. So, whenever Oracle needs to compare two PurchaseOrder_objtyp
objects, it implicitly calls the getPONo
method to do so.
The two pragma declarations provide information to PL/SQL about what sort of access the two methods need to the database.
See Also: PL/SQL User's Guide and Reference for complete details about how to use pragma declarations. |
The statement does not include the actual PL/SQL programs implementing the methods getPONo
and sumLineItems
. That appears in "Method Definitions".
The following statement completes the definition of StockItem_objtyp
, the last of the three incomplete object types declared at the beginning of this section.
CREATE TYPE StockItem_objtyp AS OBJECT ( StockNo NUMBER, Price NUMBER, TaxRate NUMBER ) /
Instances of type StockItem_objtyp
are objects representing the stock items that customers order. They have three numeric attributes.
This section shows how to specify the methods of the PurchaseOrder_objtyp
and Customer_objtyp
object types. The following statement defines the body of the PurchaseOrder_objtyp
object type (the PL/SQL programs that implement its methods):
CREATE OR REPLACE TYPE BODY PurchaseOrder_objtyp AS MAP MEMBER FUNCTION getPONo RETURN NUMBER is BEGIN RETURN PONo; END; MEMBER FUNCTION sumLineItems RETURN NUMBER is i INTEGER; StockVal StockItem_objtyp; Total NUMBER := 0; BEGIN FOR i in 1..SELF.LineItemList_ntab.COUNT LOOP UTL_REF.SELECT_OBJECT(LineItemList_ntab(i).Stock_ref,StockVal); Total := Total + SELF.LineItemList_ntab(i).Quantity * StockVal.Price; END LOOP; RETURN Total; END; END; /
The getPONo
method is simple; use it to return the purchase order number of its associated PurchaseOrder_objtyp
object.
The sumLineItems
method uses a number of O-R features:
sumLineItems
method is to return the sum of the values of the line items of its associated PurchaseOrder_objtyp
object. The keyword SELF
, which is implicitly created as a parameter to every function, lets you refer to that object.
COUNT
gives the count of the number of elements in a PL/SQL table or array. Here, in combination with LOOP
, the application iterates through all the elements in the collection -- in this case, the items of the purchase order. In this way SELF
.LineItemList_ntab
.COUNT
counts the number of elements in the nested table that match the LineItemList_ntab
attribute of the PurchaseOrder_objtyp
object, here represented by SELF
.
UTL_REF
package method is used in the implementation. The UTL_REF
package methods are necessary because Oracle does not support implicit dereferencing of REF
s within PL/SQL programs. The UTL_REF
package provides methods that operate on object references. Here, the SELECT_OBJECT
method is called to obtain the StockItem_objtyp
object corresponding to the Stock_ref
. Looking back to our data definition, you will see that Stock_ref
is an attribute of the LineItem_objtyp
object, which is itself an element of the LineItemList_ntabtyp
. Recall that a purchase order (PurchaseOrder_objtyp
) contains a list (LineItemList_ntab
) of items (LineItem_objtyp
), each of which contains a reference (Stock_ref
) to information about the item (StockItem_objtyp
). The operation that we have been considering simply fetches the required data by O-R means.
AUTHID CURRENT_USER
syntax specifies that the PurchaseOrder_objtyp
is defined invoker-rights. Therefore, the methods are executed under the rights of the current user, not under the rights of the user who defined the type.
StockVal
is of type StockItem_objtyp
. The UTL_REF
.SELECT_OBJECT
sets it to the object whose reference is the following:
(LineItemList_ntab(i)
.Stock_ref
)
This object is the actual stock item referred to in the currently selected line item.
StockVal
.Price
, the Price
attribute of the StockItem_objtyp
object. But to compute the cost of the item, you also need to know the quantity of items ordered. In the application, the term LineItemList_ntab(i)
.Quantity
represents the Quantity
attribute of the currently selected LineItem_objtyp
object.
The remainder of the method program is straightforward. The loop sums the extended values of the line items, and the method returns the total as its value.
The following statement defines the compareCustOrders
method of the Customer_objtyp
object type.
CREATE OR REPLACE TYPE BODY Customer_objtyp AS ORDER MEMBER FUNCTION compareCustOrders (x IN Customer_objtyp) RETURN INTEGER IS BEGIN RETURN CustNo - x.CustNo; END; END; /
As mentioned earlier, the function of the compareCustOrders
operation is to compare information about two customer orders. The mechanics of the operation are quite simple. The order method compareCustOrders
takes another Customer_objtyp
object as an input argument and returns the difference of the two CustNo
numbers. Because it subtracts the CustNo
of the other Customer_objtyp
object from its own object's CustNo
, the method returns one of the following:
CustNo
CustNo
CustNo
--in which case it is referring to itself.
If CustNo
has some meaning in the real world (for example, lower numbers are created earlier in time than higher numbers), then the actual value returned by this function could be useful. If either of the input arguments (SELF
and explicit) to an ORDER
method is NULL
, Oracle does not call the ORDER
method and simply treats the result as NULL
.
This completes the definition of the user-defined types used in the purchase order application. None of the declarations create tables or reserve data storage space.
To this point, the example is the same whether you plan to create and populate object tables or implement the application with object views on top of the relational tables that appear in "Implementing the Application Under The Relational Model". The remainder of this chapter continues the example using object tables. Chapter 17, "Objects in Views", picks up from this point and continues the example with object views.
Generally, you can think of the relationship between the "objects" and "object tables" in the following way:
Viewed in this way, each object table is an implicit type whose objects (specific rows) each have the same attributes (column values). The creation of explicit user-defined datatypes and object tables introduces a new level of functionality.
The following statement defines an object table Customer_objtab
to hold objects of type Customer_objtyp
:
CREATE TABLE Customer_objtab OF Customer_objtyp (CustNo PRIMARY KEY) OBJECT ID PRIMARY KEY ;
As you can see, there is a syntactic difference in the definition of object tables as opposed to relational tables, namely the use of the term "OF
" for object tables. You may recall that we earlier defined the attributes of Customer_objtyp
objects as:
CustNo NUMBER CustName VARCHAR2(200) Address_obj Address_objtyp PhoneList_var PhoneList_vartyp
This means that the object table Customer_objtab
has columns of CustNo
, CustName
, Address_obj
, and PhoneList_var
, and that each row is an object of type Customer_objtyp
. As you will see, this notion of row object offers a significant advance in functionality.
Because there is a type Customer_objtyp
, you could create numerous object tables of type Customer_objtyp
. For example, you could create an object table Customer_objtab2
also of type Customer_objtyp
. By contrast, without this ability, you would need to define each table individually.
Being able to create object tables of the same type does not mean that you cannot introduce variations. The statement that created Customer_objtab
defined a primary key constraint on the CustNo
column. This constraint applies only to this object table. Another object table of Customer_objtyp
objects (for example, Customer_objtab2
) does not need to satisfy this constraint.
Customer_objtab
contains customer objects, represented as row objects. Oracle allows row objects to be referenceable, meaning that other row objects or relational rows may reference a row object using its object identifier (OID). For example, a purchase order row object may reference a customer row object using its object reference. The object reference is an opaque system-generated value represented by the type REF
and is composed of the row object's unique OID.
Oracle requires every row object to have a unique OID. You may specify the unique OID value to be system-generated or specify the row object's primary key to serve as its unique OID. You indicate this when you execute the CREATE
TABLE
statement by specifying OBJECT
ID
PRIMARY
KEY
or OBJECT
ID
SYSTEM
GENERATED
, the latter serving as the default. The choice of primary key as the object identifier may be more efficient in cases where the primary key value is smaller than the default 16 byte system-generated identifier. For our example, the choice of primary key as the row object identifier has been made.
Examining the definition of Customer_objtab
, you can see that the Address_obj
column contains Address_objtyp
objects. In other words, an object type may have attributes that are themselves object types. These embedded objects represent composite or structured values, and are also referred to as column objects. They differ from row objects because they are not referenceable and can be NULL
.
Address_objtyp
objects have attributes of built-in types, which means that they are leaf-level scalar attributes of Customer_objtyp
. Oracle creates columns for Address_objtyp
objects and their attributes in the object table Customer_objtab
. You can refer to these columns using the dot notation. For example, if you want to build an index on the Zip
column, then you can refer to it as Address
.Zip
.
The PhoneList
column contains varrays of type PhoneList_vartyp
. You may recall that we defined each object of type PhoneList_vartyp
as a varray of up to 10 telephone numbers, each represented by a data item of type VARCHAR2
. Here is the CREATE TYPE
statement that created PhoneList_vartyp
:
CREATE TYPE PhoneList_vartyp AS VARRAY(10) OF VARCHAR2(20) /
Because each varray of type PhoneList_vartyp
can contain no more than 200 characters (10 x 20), plus a small amount of overhead, Oracle stores the varray as a single data unit in the PhoneList_var
column. Oracle stores varrays that exceed 4000 bytes in "inline" BLOB
s, which means that a portion of the varray value could potentially be stored outside the table.
The next statement creates an object table for StockItem_objtyp
objects:
CREATE TABLE Stock_objtab OF StockItem_objtyp (StockNo PRIMARY KEY) OBJECT ID PRIMARY KEY ;
This statement does not introduce anything new. The statement creates the Stock_objtab
object table. Each row of the table is a StockItem_objtyp
object having three numeric attributes:
StockNo NUMBER Price NUMBER TaxRate NUMBER
Oracle assigns a column for each attribute, and the CREATE
TABLE
statement places a primary key constraint on the StockNo
column, and specifies that the primary key be used as the row object's identifier.
The next statement defines an object table for PurchaseOrder_objtyp
objects:
CREATE TABLE PurchaseOrder_objtab OF PurchaseOrder_objtyp ( /* Line 1 */ PRIMARY KEY (PONo), /* Line 2 */ FOREIGN KEY (Cust_ref) REFERENCES Customer_objtab) /* Line 3 */ OBJECT ID PRIMARY KEY /* Line 4 */ NESTED TABLE LineItemList_ntab STORE AS PoLine_ntab ( /* Line 5 */ (PRIMARY KEY(NESTED_TABLE_ID, LineItemNo)) /* Line 6 */ ORGANIZATION INDEX COMPRESS) /* Line 7 */ RETURN AS LOCATOR /* Line 8 */ /
The SCOPE
FOR
constraint on a REF
is not allowed in a CREATE
TABLE
statement. Therefore, to specify that Stock_ref
can reference only the object table Stock_objtab
, issue the following ALTER
TABLE
statement on the PoLine_ntab
storage table:
ALTER TABLE PoLine_ntab ADD (SCOPE FOR (Stock_ref) IS stock_objtab) ;
Note that this statement is executed on the storage table, not the parent table.
The preceding CREATE TABLE
statement creates the PurchaseOrder_objtab
object table. This statement requires some explanation; hence, it has been annotated with line numbers on the right:
CREATE TABLE PurchaseOrder_objtab OF PurchaseOrder_objtyp (
This line indicates that each row of the table is a PurchaseOrder_objtyp
object. Attributes of PurchaseOrder_objtyp
objects are:
PONo NUMBER Cust_ref REF Customer_objtyp OrderDate DATE ShipDate DATE LineItemList_ntab LineItemList_ntabtyp ShipToAddr_obj Address_objtyp
PRIMARY KEY (PONo),
This line specifies that the PONo
attribute is the primary key for the table.
FOREIGN KEY (Cust_ref) REFERENCES Customer_objtab)
This line specifies a referential constraint on the Cust_ref
column. This referential constraint is similar to those specified for relational tables. When there is no constraint, the REF
column allows you to reference any row object. However, in this case, the Cust_ref
REF
s can refer only to row objects in the Customer_objtab
object table.
OBJECT ID PRIMARY KEY
This line indicates that the primary key of the PurchaseOrder_objtab
object table be used as the row's OID.
NESTED TABLE LineItemList_ntab STORE AS PoLine_ntab ( (PRIMARY KEY(NESTED_TABLE_ID, LineItemNo)) ORGANIZATION INDEX COMPRESS) RETURN AS LOCATOR
These lines pertain to the storage specification and properties of the nested table column, LineItemList_ntab
. Recall from Oracle8i Concepts that the rows of a nested table are stored in a separate storage table. This storage table is not directly queryable by the user but can be referenced in DDL statements for maintenance purposes. A hidden column in the storage table, called the NESTED_TABLE_ID,
matches the rows with their corresponding parent row. All the elements in the nested table belonging to a particular parent have the same NESTED_TABLE_ID
value. For example, all the elements of the nested table of a given row of PurchaseOrder_objtab
have the same value of NESTED_TABLE_ID
. The nested table elements that belong to a different row of PurchaseOrder_objtab
have a different value of NESTED_TABLE_ID
.
In the CREATE
TABLE
example above, Line 5 indicates that the rows of LineItemList_ntab
nested table are to be stored in a separate table (referred to as the storage table) named PoLine_ntab
. The STORE
AS
clause also allows you to specify the constraint and storage specification for the storage table. In this example, Line 7 indicates that the storage table is an index-organized table (IOT
). In general, storing nested table rows in an IOT is beneficial, because it provides clustering of rows belonging to the same parent. The specification of COMPRESS
on the IOT
saves storage space because, if you do not specify COMPRESS
, the NESTED_TABLE_ID
part of the IOT
's key is repeated for every row of a parent row object. If, however, you specify COMPRESS
, the NESTED_TABLE_ID
is stored only once for each row of a parent row object.
See Also: "Nested Table Storage" for information about the benefits of organizing a nested table as and IOT and specifying nested table compression, and for more information about nested table storage. |
In Line 6, the specification of NESTED_TABLE_ID
and LineItemNo
attribute as the primary key for the storage table serves two purposes: first, it serves as the key for the IOT
; second, it enforces uniqueness of a column (LineItemNo
) of a nested table within each row of the parent table. By including the LineItemNo
column in the key, the statement ensures that the LineItemNo
column contains distinct values within each purchase order.
Line 8 indicates that the nested table, LineItemList_ntab
, is to be returned in the locator form when retrieved. If you do not specify LOCATOR
, the default is VALUE
, which indicates that the entire nested table is to be returned instead of just a locator to the nested table. When the cardinality of the nested table collection is high, it may not be very efficient to return the entire nested table whenever the containing row object or the column is selected.
Specifying that the nested table's locator is to be returned enables Oracle to send to the client only a locator to the actual collection value. An application may ascertain whether a fetched nested table is in the locator or value form by calling the OCICollIsLocator
or UTL_COLL
.IS_LOCATOR
interfaces. Once it is determined that the locator has been returned, the application may query using the locator to fetch only the desired subset of row elements in the nested table. This locator-based retrieval of the nested table rows is based on the original statement's snapshot, to preserve the value or copy semantics of the nested table. That is, when the locator is used to fetch a subset of row elements in the nested table, the nested table snapshot reflects the nested table when the locator was first retrieved.
Recall the implementation of the sumLineItems
method of PurchaseOrder_objtyp
in "Method Definitions". That implementation assumed that the LineItemList_ntab
nested table would be returned as a VALUE
. In order to handle large nested tables more efficiently, and to take advantage of the fact that the nested table in the PurchaseOrder_objtab
is returned as a locator, the sumLineItems
method would need to be rewritten as follows:
CREATE OR REPLACE TYPE BODY PurchaseOrder_objtyp AS MAP MEMBER FUNCTION getPONo RETURN NUMBER is BEGIN RETURN PONo; END; MEMBER FUNCTION sumLineItems RETURN NUMBER IS i INTEGER; StockVal StockItem_objtyp; Total NUMBER := 0; BEGIN IF (UTL_COLL.IS_LOCATOR(LineItemList_ntab)) -- check for locator THEN SELECT SUM(L.Quantity * L.Stock_ref.Price) INTO Total FROM TABLE(CAST(LineItemList_ntab AS LineItemList_ntabtyp)) L; ELSE FOR i in 1..SELF.LineItemList_ntab.COUNT LOOP UTL_REF.SELECT_OBJECT(LineItemList_ntab(i).Stock_ref,StockVal); Total := Total + SELF.LineItemList_ntab(i).Quantity * StockVal.Price; END LOOP; END IF; RETURN Total; END; END; /
In the above implementation of sumLineItems
method, a check is made to ascertain whether the nested table attribute, LineItemList_ntab
, is returned as a locator using the UTL_COLL
.IS_LOCATOR
function. In the case where the condition evaluates to TRUE
, the nested table locator is queried using the TABLE
expression.
The querying of the nested table locator results in a more efficient processing of the large line item list of a purchase order. The previous code segment of iterating over the LineItemList_ntab
in the program is retained to deal with the case where the nested table is returned as a VALUE
.
After the table is created, the following ALTER TABLE
statement is issued:
ALTER TABLE PoLine_ntab ADD (SCOPE FOR (Stock_ref) IS stock_objtab);
This statement specifies that the Stock_ref
column of the nested table is scoped to Stock_objtab
. This indicates that the values stored in this column must be references to row objects in Stock_objtab
. The SCOPE
constraint is different from the referential constraint, because the SCOPE
constraint has no implication on the referenced object. For example, any referenced row object in Stock_objtab
may be deleted, even if it is referenced in the Stock_ref
column of the nested table. Such a deletion renders the corresponding reference in the nested table a DANGLING REF
.
Oracle does not support referential constraint specification for storage tables. In this situation, specifying the SCOPE
clause for a REF
column is useful. In general, specifying scope or referential constraints for REF
columns has a few benefits:
REF
value in the column.
REF
column.
REF
s as joins involving the referenced table.
At this point, all of the tables for the purchase order application are in place. The next section shows how to operate on these tables.
The statements in this section show how to insert the same data into the object tables just created as the earlier statements inserted values into relational tables.
INSERT INTO Stock_objtab VALUES(1004, 6750.00, 2) ; INSERT INTO Stock_objtab VALUES(1011, 4500.23, 2) ; INSERT INTO Stock_objtab VALUES(1534, 2234.00, 2) ; INSERT INTO Stock_objtab VALUES(1535, 3456.23, 2) ;
INSERT INTO Customer_objtab VALUES ( 1, 'Jean Nance', Address_objtyp('2 Avocet Drive', 'Redwood Shores', 'CA', '95054'), PhoneList_vartyp('415-555-1212') ) ; INSERT INTO Customer_objtab VALUES ( 2, 'John Nike', Address_objtyp('323 College Drive', 'Edison', 'NJ', '08820'), PhoneList_vartyp('609-555-1212','201-555-1212') ) ;
INSERT INTO PurchaseOrder_objtab SELECT 1001, REF(C), SYSDATE, '10-MAY-1999', LineItemList_ntabtyp(), NULL FROM Customer_objtab C WHERE C.CustNo = 1 ;
The preceding statement constructs a PurchaseOrder_objtyp
object with the following attributes:
PONo 1001 Cust_ref REF to customer number 1 OrderDate SYSDATE ShipDate 10-MAY-1999 LineItemList_ntab an empty LineItem_ntabtyp ShipToAddr_obj NULL
The statement uses a query to construct a REF
to the row object in the Customer_objtab
object table that has a CustNo
value of 1
.
The following statement uses a TABLE
expression to identify the nested table as the target for the insertion, namely the nested table in the LineItemList_ntab
column of the row object in the PurchaseOrder_objtab
table that has a PONo
value of 1001.
INSERT INTO TABLE ( SELECT P.LineItemList_ntab FROM PurchaseOrder_objtab P WHERE P.PONo = 1001 ) SELECT 01, REF(S), 12, 0 FROM Stock_objtab S WHERE S.StockNo = 1534 ;
The preceding statement inserts a line item into the nested table identified by the TABLE
expression. The line item that it inserts contains a REF
to the row object in the object table Stock_objtab
that has a StockNo
value of 1534
.
The following statements are similar to the preceding two:
INSERT INTO PurchaseOrder_objtab SELECT 2001, REF(C), SYSDATE, '20-MAY-1997', LineItemList_ntabtyp(), Address_objtyp('55 Madison Ave','Madison','WI','53715') FROM Customer_objtab C WHERE C.CustNo = 2 ; INSERT INTO TABLE ( SELECT P.LineItemList_ntab FROM PurchaseOrder_objtab P WHERE P.PONo = 1001 ) SELECT 02, REF(S), 10, 10 FROM Stock_objtab S WHERE S.StockNo = 1535 ; INSERT INTO TABLE ( SELECT P.LineItemList_ntab FROM PurchaseOrder_objtab P WHERE P.PONo = 2001 ) SELECT 10, REF(S), 1, 0 FROM Stock_objtab S WHERE S.StockNo = 1004 ; INSERT INTO TABLE ( SELECT P.LineItemList_ntab FROM PurchaseOrder_objtab P WHERE P.PONo = 2001 ) VALUES(11, (SELECT REF(S) FROM Stock_objtab S WHERE S.StockNo = 1011), 2, 1) ;
The following query statement implicitly invokes a comparison method. It shows how Oracle uses the ordering of PurchaseOrder_objtyp
object types that the comparison method defines:
SELECT p.PONo FROM PurchaseOrder_objtab p ORDER BY VALUE(p) ;
The preceding instruction causes Oracle to invoke the map method getPONo
for each PurchaseOrder_objtyp
object in the selection. Because that method simply returns the value of the object's PONo
attribute, the result of the selection is a list of purchase order numbers in ascending numerical order.
The following queries correspond to the queries executed under the relational model.
SELECT DEREF(p.Cust_ref), p.ShipToAddr_obj, p.PONo, p.OrderDate, LineItemList_ntab FROM PurchaseOrder_objtab p WHERE p.PONo = 1001 ;
SELECT p.PONo, p.sumLineItems() FROM PurchaseOrder_objtab p ;
SELECT po.PONo, po.Cust_ref.CustNo, CURSOR ( SELECT * FROM TABLE (po.LineItemList_ntab) L WHERE L.Stock_ref.StockNo = 1004 ) FROM PurchaseOrder_objtab po ;
The above query returns a nested cursor for the set of LineItem_obj
objects selected from the nested table. The application can fetch from the nested cursor to obtain the individual LineItem_obj
objects. The above query can be alternatively expressed by unnesting the nested set with respect to the outer result as follows:
SELECT po.PONo, po.Cust_ref.CustNo, L.* FROM PurchaseOrder_objtab po, TABLE (po.LineItemList_ntab) L WHERE L.Stock_ref.StockNo = 1004 ;
The above query returns the result set as a "flattened" form (or First Normal Form). This type of query is useful when accessing Oracle collection columns from relational tools and APIs, such as ODBC. In the above unnesting example, only the rows of the PurchaseOrder_objtab
object table that has any LineItemList_ntab
rows are returned. If all rows of PurchaseOrder_objtab
table are to be fetched, irrespective of the presence of any rows in their corresponding LineItemList_ntab
, then the (+) operator is required as illustrated in the following query:
SELECT po.PONo, po.Cust_ref.CustNo, L.* FROM PurchaseOrder_objtab po, TABLE (po.LineItemList_ntab) (+) L WHERE L.Stock_ref.StockNo = 1004 ;
This request requires the rows of all nested tables, LineItemList_ntab
, of all PurchaseOrder_objtab
rows be queried. Again, unnesting is required for the following query:
SELECT AVG(L.DISCOUNT) FROM PurchaseOrder_objtab po, TABLE (po.LineItemList_ntab) L ;
The following example has the same effect as the two deletions needed in the relational case (see "Deleting Data Under The Relational Model"). In this case, Oracle automatically deletes all line items belonging to the deleted purchase order. The relational case requires a separate step.
DELETE FROM PurchaseOrder_objtab WHERE PONo = 1001 ;
This concludes the object table version of the purchase order example. The next chapter develops an alternative version of the example using relational tables and object views.
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. Oracle8i extends your 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.
The following example partitions the purchase order table along zip codes (ToZip
), which is an attribute of the ShipToAddr
embedded column object. For the purposes of this example, the LineItemList
nested table was made a varray to illustrate storage for the partitioned varray.
Assuming that the LineItemList
is defined as a varray:
CREATE TYPE LineItemList_vartyp as varray(10000) of LineItem_objtyp / CREATE TYPE PurchaseOrder_typ AS OBJECT ( PONo NUMBER, Cust_ref REF Customer_objtyp, OrderDate DATE, ShipDate DATE, OrderForm BLOB, LineItemList LineItemList_vartyp, ShipToAddr Address_objtyp, MAP MEMBER FUNCTION ret_value RETURN NUMBER, PRAGMA RESTRICT_REFERENCES ( ret_value, WNDS, WNPS, RNPS, RNDS), MEMBER FUNCTION total_value RETURN NUMBER, PRAGMA RESTRICT_REFERENCES (total_value, WNDS, WNPS) ) / CREATE TABLE PurchaseOrders_tab of PurchaseOrder_typ LOB (OrderForm) store as (nocache logging) PARTITION BY RANGE (ShipToAddr.zip) (PARTITION PurOrderZone1_part VALUES LESS THAN ('59999') LOB (OrderForm) store as ( storage (INITIAL 10 MINEXTENTS 10 MAXEXTENTS 100)) VARRAY LineItemList store as LOB ( storage (INITIAL 10 MINEXTENTS 10 MAXEXTENTS 100)), PARTITION PurOrderZone6_part VALUES LESS THAN ('79999') LOB (OrderForm) store as ( storage (INITIAL 10 MINEXTENTS 10 MAXEXTENTS 100)) VARRAY LineItemList store as LOB ( storage (INITIAL 10 MINEXTENTS 10 MAXEXTENTS 100)), PARTITION PurOrderZoneO_part VALUES LESS THAN ('99999') LOB (OrderForm) store as ( storage (INITIAL 10 MINEXTENTS 10 MAXEXTENTS 100)) VARRAY LineItemList store as LOB ( storage (INITIAL 10 MINEXTENTS 10 MAXEXTENTS 100))) ;