Oracle® Database SQL Reference 10g Release 2 (10.2) Part Number B14200-02 |
|
|
View PDF |
This section describes some of the ways you can use XMLType
data in the database.
XMLType Tables
The sample schema oe
contains a table warehouses
, which contains an XMLType
column warehouse_spec
. Suppose you want to create a separate table with the warehouse_spec
information. The following example creates a very simple XMLType
table with one implicit CLOB
column:
CREATE TABLE xwarehouses OF XMLTYPE;
You can insert into such a table using XMLType
syntax, as shown in the next statement. (The data inserted in this example corresponds to the data in the warehouse_spec
column of the sample table oe.warehouses
where warehouse_id
= 1.)
INSERT INTO xwarehouses VALUES (xmltype('<?xml version="1.0"?> <Warehouse> <WarehouseId>1</WarehouseId> <WarehouseName>Southlake, Texas</WarehouseName> <Building>Owned</Building> <Area>25000</Area> <Docks>2</Docks> <DockType>Rear load</DockType> <WaterAccess>true</WaterAccess> <RailAccess>N</RailAccess> <Parking>Street</Parking> <VClearance>10</VClearance> </Warehouse>'));
You can query this table with the following statement:
SELECT e.getClobVal() FROM xwarehouses e;
Because Oracle implicitly stores the data in a CLOB
column, it is subject to all of the restrictions on LOB columns. To avoid these restrictions, create an XMLSchema-based table. The XMLSchema maps the XML elements to their object-relational equivalents. The following example registers an XMLSchema locally. The XMLSchema (xwarhouses.xsd
) reflects the same structure as the xwarehouses
table. (XMLSchema declarations use PL/SQL and the DBMS_XMLSCHEMA
package, so the example is shown in italics.)
begin dbms_xmlschema.registerSchema( 'http://www.oracle.com/xwarehouses.xsd', '<schema xmlns="http://www.w3.org/2001/XMLSchema" targetNamespace="http://www.oracle.com/xwarehouses.xsd" xmlns:who="http://www.oracle.com/xwarehouses.xsd" version="1.0"> <simpleType name="RentalType"> <restriction base="string"> <enumeration value="Rented"/> <enumeration value="Owned"/> </restriction> </simpleType> <simpleType name="ParkingType"> <restriction base="string"> <enumeration value="Street"/> <enumeration value="Lot"/> </restriction> </simpleType> <element name = "Warehouse"> <complexType> <sequence> <element name = "WarehouseId" type = "positiveInteger"/> <element name = "WarehouseName" type = "string"/> <element name = "Building" type = "who:RentalType"/> <element name = "Area" type = "positiveInteger"/> <element name = "Docks" type = "positiveInteger"/> <element name = "DockType" type = "string"/> <element name = "WaterAccess" type = "boolean"/> <element name = "RailAccess" type = "boolean"/> <element name = "Parking" type = "who:ParkingType"/> <element name = "VClearance" type = "positiveInteger"/> </sequence> </complexType> </element> </schema>', TRUE, TRUE, FALSE, FALSE); end; /
Now you can create an XMLSchema-based table, as shown in the following example:
CREATE TABLE xwarehouses OF XMLTYPE XMLSCHEMA "http://www.oracle.com/xwarehouses.xsd" ELEMENT "Warehouse";
By default, Oracle stores this as an object-relational table. Therefore, you can insert into it as shown in the example that follows. (The data inserted in this example corresponds to the data in the warehouse_spec
column of the sample table oe.warehouses
where warehouse_id
= 1.)
INSERT INTO xwarehouses VALUES( xmltype.createxml('<?xml version="1.0"?> <who:Warehouse xmlns:who="http://www.oracle.com/xwarehouses.xsd" xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" xsi:schemaLocation="http://www.oracle.com/xwarehouses.xsd http://www.oracle.com/xwarehouses.xsd"> <WarehouseId>1</WarehouseId> <WarehouseName>Southlake, Texas</WarehouseName> <Building>Owned</Building> <Area>25000</Area> <Docks>2</Docks> <DockType>Rear load</DockType> <WaterAccess>true</WaterAccess> <RailAccess>false</RailAccess> <Parking>Street</Parking> <VClearance>10</VClearance> </who:Warehouse>')); ...
You can define constraints on an XMLSchema-based table. To do so, you use the XMLDATA
pseudocolumn to refer to the appropriate attribute within the Warehouse
XML element:
ALTER TABLE xwarehouses ADD (PRIMARY KEY(XMLDATA."WarehouseId"));
Because the data in xwarehouses
is stored object relationally, Oracle rewrites queries to this XMLType
table to go to the underlying storage when possible. Therefore the following queries would use the index created by the primary key constraint in the preceding example:
SELECT * FROM xwarehouses x WHERE EXISTSNODE(VALUE(x), '/Warehouse[WarehouseId="1"]') = 1, 'xmlns:who="http://www.oracle.com/xwarehouses.xsd"') = 1; SELECT * FROM xwarehouses x WHERE EXTRACTVALUE(VALUE(x), '/Warehouse/WarehouseId') = 1, 'xmlns:who="http://www.oracle.com/xwarehouses.xsd"') = 1;
You can also explicitly create indexes on XMLSchema-based tables, which greatly enhance the performance of subsequent queries. You can create object-relational views on XMLType
tables, and you can create XMLType
views on object-relational tables.
XMLType Columns
The sample table oe.warehouses
was created with a warehouse_spec
column of type XMLType
. No storage was specified, so the XMLType
column was implicitly stored as a CLOB
. The examples in this section create a shortened form of the oe.warehouses
table, using two different types of storage.
The first example creates a table with an XMLType
table stored as a CLOB
. This table does not require an XMLSchema, so the content structure is not predetermined:
CREATE TABLE xwarehouses ( warehouse_id NUMBER, warehouse_spec XMLTYPE) XMLTYPE warehouse_spec STORE AS CLOB (TABLESPACE example STORAGE (INITIAL 6144 NEXT 6144) CHUNK 4000 NOCACHE LOGGING);
The following example creates a similar table, but stores the XMLType
data in an object-relational XMLType
column whose structure is determined by the specified XMLSchema:
CREATE TABLE xwarehouses ( warehouse_id NUMBER, warehouse_spec XMLTYPE) XMLTYPE warehouse_spec STORE AS OBJECT RELATIONAL XMLSCHEMA "http://www.oracle.com/xwarehouses.xsd" ELEMENT "Warehouse";