Oracle9i XML Developer's Kits Guide - XDK Release 2 (9.2) Part Number A96621-01 |
|
This chapter contains the following sections:
XML has become the format for data interchange. At the same time, a substantial amount of business data resides in object-relational databases. It is therefore necessary to have the ability to transform this relational data to XML.
XML SQL Utility (XSU) enables you to do this as follows:
For example, on the XML generation side, when given the query SELECT * FROM emp
, XSU queries the database and returns the results as the following XML document:
<?xml version='1.0'?> <ROWSET> <ROW num="1"> <EMPNO>7369</EMPNO> <ENAME>Smith</ENAME> <JOB>CLERK</JOB> <MGR>7902</MGR> <HIREDATE>12/17/1980 0:0:0</HIREDATE> <SAL>800</SAL> <DEPTNO>20</DEPTNO> </ROW> <!-- additional rows ... --> </ROWSET>
Going the other way, given the XML document preceding, XSU can extract the data from it and insert it into the scott.emp
table in the database.
XML SQL Utility functionality can be accessed in the following ways:
XSU can perform the following tasks:
ROW
element. You can also register an XSL transformation which is then applied to the generated XML documents as needed.Starting in Oracle9i, XSU can also perform the following tasks:
From Oracle9i Release 2 (9.2), XSU supports XMLType. Using XSU with XMLType is useful if, for example, you have XMLType columns in objects or tables.
See Also:
Oracle9i XML Database Developer's Guide - Oracle XML DB, in particular, the chapter on Generating XML, for examples on using XSU with XMLType. |
XML SQL Utility (XSU) needs the following components:
XML SQL Utility (XSU) is packaged with Oracle8i (8.1.7 and later) and Oracle9i. XSU is made up of three files:
$ORACLE_HOME/rdbms/jlib/xsu12.jar
-- Contains all the Java classes which make up XSU. xsu12
requires JDK1.2.x
and JDBC2.x
. This is the XSU version loaded into Oracle9i.$ORACLE_HOME/rdbms/jlib/xsu111.jar
-- Contains the same classes as xsu12.jar,
except that xsu111
requires JDK1.1.x
and JDBC1.x
.$ORACLE_HOME/rdbms/admin/dbmsxsu.sql
-- This is the SQL script that builds the XSU PL/SQL API. xsu12.jar
needs to be loaded into the database before dbmsxsu.sql
is executed.By default the Oracle9i installer installs XSU on the hard drive in the locations specified earlier. It also loads it into the database.
If during initial installation you choose to not install XSU, you can install it later, but the installation becomes less simple. To install XSU later, first install XSU and its dependent components on your system. You can accomplish this using Oracle Installer. Next perform the following steps:
$ORACLE_HOME/xdk/lib
. Here you will find xmlparserv2.jar
that you need to load into the database. To do this, see "Loading JAVA Classes" in the Oracle9i Java Stored Procedures Developer's Guide$ORACLE_HOME/admin
and run catxsu.sql
Note: XML SQL Utility (XSU) is part of the XDK for Java and is also available on OTN at: |
XML SQL Utility (XSU) is written in Java, and can live in any tier that supports Java.
The Java classes which make up XSU can be loaded into Java-enabled Oracle8i or later. Also, XSU contains a PL/SQL wrapper that publishes the XSU Java API to PL/SQL, creating a PL/SQL API. This way you can:
Figure 8-1 shows the typical architecture for such a system. XML generated from XSU running in the database, can be placed in advanced queues in the database to be queued to other systems or clients. The XML can be used from within stored procedures in the database or shipped outside through web servers or application servers.
Note: In Figure 8-1, all lines are bi-directional. Since XSU can generate as well as save data, data can come from various sources to XSU running inside the database, and can be put back in the appropriate database tables. |
Your application architecture may need to use an application server in the middle tier, separate from the database. The application tier can be an Oracle database, Oracle9i Application Server, or a third party application server that supports Java programs.
You may want to generate XML in the middle tier, from SQL queries or ResultSets, for various reasons. For example, to integrate different JDBC data sources in the middle tier. In this case you could install the XSU in your middle tier and your Java programs could make use of XSU through its Java API.
Figure 8-2, shows how a typical architecture for running XSU in a middle tier. In the middle tier, data from JDBC sources is converted by XSU into XML and then sent to Web servers or other systems. Again, the whole process is bi-directional and the data can be put back into the JDBC sources (database tables or views) using XSU. If an Oracle database itself is used as the application server, then you can also use the PL/SQL front-end instead of Java.
XSU can live in the Web server, as long as the Web server supports Java servlets. This way you can write Java servlets that use XSU to accomplish their task.
XSQL servlet does just this. XSQL servlet is a standard servlet provided by Oracle. It is built on top of XSU and provides a template-like interface to XSU functionality. If XML processing in the Web server is your goal, you should probably use the XSQL servlet, as it will spare you from the intricate servlet programming.
See:
Chapter 9, "XSQL Pages Publishing Framework" for information about using XSQL Servlet. |
XML SQL Utility can be also installed on a client system, where you can write Java programs that use XSU. You can also use XSU directly through its command line front end.
As described earlier, XML SQL Utility transforms data retrieved from object-relational database tables or views into XML. XSU can also extract data from an XML document, and using a specified mapping, insert the data into appropriate columns or attributes of a table or a view in the database. This section describes the canonical mapping or transformation used to go from SQL to XML or vice versa.
Consider table emp
:
CREATE TABLE emp ( EMPNO NUMBER, ENAME VARCHAR2(20), JOB VARCHAR2(20), MGR NUMBER, HIREDATE DATE, SAL NUMBER, DEPTNO NUMBER );
XSU can generate the following XML document by specifying the query, select * from emp
:
<?xml version='1.0'?> <ROWSET> <ROW num="1"> <EMPNO>7369</EMPNO> <ENAME>Smith</ENAME> <JOB>CLERK</JOB> <MGR>7902</MGR> <HIREDATE>12/17/1980 0:0:0</HIREDATE> <SAL>800</SAL> <DEPTNO>20</DEPTNO> </ROW> <!-- additional rows ... --> </ROWSET>
In the generated XML, the rows returned by the SQL query are enclosed in a ROWSET
tag to constitute the <ROWSET>
element. This element is also the root element of the generated XML document.
<ROWSET>
element contains one or more <ROW>
elements.<ROW>
elements contain the data from one of the returned database table rows. Specifically, each <ROW>
element contains one or more elements whose names and content are those of the database columns specified in the SELECT
list of the SQL query.Next we describe this mapping but against an object-relational schema. Consider the following type, AddressType
. Its an object type whose attributes are all scalar types and is created as follows:
CREATE TYPE AddressType AS OBJECT ( STREET VARCHAR2(20), CITY VARCHAR2(20), STATE CHAR(2), ZIP VARCHAR2(10) ); /
The following type, EmployeeType
, is also an object type but it has an EMPADDR
attribute that is of an object type itself, specifically, AddressType
. Employee Type
is created as follows:
CREATE TYPE EmployeeType AS OBJECT ( EMPNO NUMBER, ENAME VARCHAR2(20), SALARY NUMBER, EMPADDR AddressType ); /
The following type, EmployeeListType
, is a collection type whose elements are of the object type, EmployeeType
. EmployeeListType
is created as follows:
CREATE TYPE EmployeeListType AS TABLE OF EmployeeType; /
Finally, dept
is a table with, among other things, an object type column and a collection type column -- AddressType
and EmployeeListType
respectively.
CREATE TABLE dept ( DEPTNO NUMBER, DEPTNAME VARCHAR2(20), DEPTADDR AddressType, EMPLIST EmployeeListType ) NESTED TABLE EMPLIST STORE AS EMPLIST_TABLE;
Assume that valid values are stored in table, dept
. For the query select * from dept
, XSU generates the following XML document:
<?xml version='1.0'?> <ROWSET> <ROW num="1"> <DEPTNO>100</DEPTNO> <DEPTNAME>Sports</DEPTNAME> <DEPTADDR> <STREET>100 Redwood Shores Pkwy</STREET> <CITY>Redwood Shores</CITY> <STATE>CA</STATE> <ZIP>94065</ZIP> </DEPTADDR> <EMPLIST> <EMPLIST_ITEM num="1"> <EMPNO>7369</EMPNO> <ENAME>John</ENAME> <SALARY>10000</SALARY> <EMPADDR> <STREET>300 Embarcadero</STREET> <CITY>Palo Alto</CITY> <STATE>CA</STATE> <ZIP>94056</ZIP> </EMPADDR> </EMPLIST_ITEM> <!-- additional employee types within the employee list --> </EMPLIST> </ROW> <!-- additional rows ... --> </ROWSET>
As in the last example, the mapping is canonical, that is, <ROWSET>
contains <ROW>
s that contain elements corresponding to the columns. As before, the elements corresponding to scalar type columns simply contain the data from the column.
Things get more complex with elements corresponding to a complex type column. For example, <DEPTADDR>
corresponds to the DEPTADDR
column which is of object type ADDRESS
. Consequently, <DEPTADDR>
contains subelements corresponding to the attributes specified in the type ADDRESS
. These subelements can contain data or sub-elements of their own, again depending if the attribute they correspond to is of a simple or complex type.
When dealing with elements corresponding to database collections, things are yet different. Specifically, the <EMPLIST>
element corresponds to the EMPLIST
column which is of a EmployeeListType
collection type. Consequently, the <EMPLIST>
element contains a list of <EMPLIST_ITEM>
elements each corresponding to one of the elements of the collection.
Other observations to make about the preceding mapping are:
<ROW>
elements contain a cardinality attribute num
.Often, one needs to generate XML with a specific structure. Since the desired structure may differ from the default structure of the generated XML document, it is desirable to have some flexibility in this process. You can customize the structure of a generated XML document using one of the following methods:
Source customizations are done by altering the query or database schema. The simplest and most powerful source customizations include the following:
select empno as "@empno",... from emp
, results in an XML document where the <ROW>
element has an attribute EMPNO
.XML SQL Utility enables you to modify the mapping it uses to transform SQL data into XML. You can make any of the following SQL to XML mapping changes:
<ROWSET>
tag.<ROW>
tag.num
. This is the cardinality attribute of the <ROW>
element.Finally, if the desired customizations cannot be achieved with the foregoing methods, you can write an XSL transformation and register it with XSU. While there is an XSLT registered with the XSU, XSU can apply the XSLT to any XML it generates.
XML to SQL mapping is just the reverse of the SQL to XML mapping.
Consider the following differences when mapping from XML to SQL, compared to mapping from SQL to XML:
If the XML document does not perfectly map into the target database schema, there are three things you can do:
This section describes how XSU works when performing the following tasks:
XSU generation is simple. SQL queries are executed and the resultset is retrieved from the database. Metadata about the resultset is acquired and analyzed. Using the mapping described in "Default SQL-to-XML Mapping" , the SQL result set is processed and converted into an XML document.
To insert the contents of an XML document into a particular table or view, XSU first retrieves the metadata about the target table or view. Based on the metadata, XSU generates a SQL INSERT
statement. XSU extracts the data out of the XML document and binds it to the appropriate columns or attributes. Finally the statement is executed.
For example, assume that the target table is dept
and the XML document is the one generated from dept
.
XSU generates the following INSERT
statement.
INSERT INTO Dept (DEPTNO, DEPTNAME, DEPTADDR, EMPLIST) VALUES (?,?,?,?)
Next, the XSU parses the XML document, and for each record, it binds the appropriate values to the appropriate columns or attributes, and executes the statement:
DEPTNO <- 100 DEPTNAME <- SPORTS DEPTADDR <- AddressType('100 Redwood Shores Pkwy','Redwood Shores', 'CA','94065') EMPLIST <- EmployeeListType(EmployeeType(7369,'John',100000, AddressType('300 Embarcadero','Palo Alto','CA','94056'),...)
Insert processing can be optimized to insert in batches, and commit in batches. More detail on batching can be found in the section on "Insert Processing Using XSU (Java API)".
Updates and deletes differ from inserts in that they can affect more than one row in the database table. For inserts, each ROW
element of the XML document can affect at most, one row in the table, if there are no triggers or constraints on the table.
However, with both updates and deletes, the XML element could match more than one row if the matching columns are not key columns in the table. For updates, you must provide a list of key columns which XSU needs to identify the row to update. For example, to update the DEPTNAME
to SportsDept
instead of Sports
, you can have an XML document such as:
<ROWSET> <ROW num="1"> <DEPTNO>100</DEPTNO> <DEPTNAME>SportsDept</DEPTNAME> </ROW> </ROWSET>
and supply the DEPTNO
as the key column. This would result in the following UPDATE
statement:
UPDATE DEPT SET DEPTNAME = ? WHERE DEPTNO = ?
and bind the values,
DEPTNO <- 100 DEPTNAME <- SportsDept
For updates, you can also choose to update only a set of columns and not all the elements present in the XML document. See also, "Update Processing Using XSU (Java API)" .
For deletes, you can choose to give a set of key columns for the delete to identify the rows. If the set of key columns are not given, then the DELETE
statement tries to match all the columns given in the document. For an XML document:
<ROWSET> <ROW num="1"> <DEPTNO>100</DEPTNO> <DEPTNAME>Sports</DEPTNAME> <DEPTADDR> <STREET>100 Redwood Shores Pkwy</STREET> <CITY>Redwood Shores</CITY> <STATE>CA</STATE> <ZIP>94065</ZIP> </DEPTADDR> </ROW> <!-- additional rows ... --> </ROWSET>
To delete, XSU fires off a DELETE
statement (one for each ROW
element) which looks like the following:
DELETE FROM Dept WHERE DEPTNO = ? AND DEPTNAME = ? AND DEPTADDR = ? binding, DEPTNO <- 100 DEPTNAME <- Sports DEPTADDR <- AddressType('100 Redwood Shores Pkwy','Redwood City','CA','94065')
See also, "Delete Processing Using XSU (Java API)" .
XSU comes with a simple command line front end which gives you quick access to XML generation and insertion.
The XSU command line options are provided through the Java class, OracleXML
. Invoke it by calling:
java OracleXML
This prints the front end usage information. To run the XSU command line front end, first specify where the executable is located. Add the following to your CLASSPATH
:
Also, since XSU depends on Oracle XML Parser and JDBC drivers, make the location of these components known. To do this, the CLASSPATH
must include the locations of:
xmlparserv2.jar
)classes12.jar
if using xsu12.jar
or classes111.jar
if using xsu111.jar
)For XSU generation capabilities, use the XSU getXML
parameter. For example, to generate an XML document by querying the emp
table in the scott
schema, use:
java OracleXML getXML -user "scott/tiger" "select * from emp"
This performs the following tasks:
select * from emp
The getXML
parameter supports a wide range of options which are explained in the following section.
Table 8-1 lists the OracleXML getXML
options:
To insert an XML document into the emp
table in the scott
schema, use the following syntax:
java OracleXML putXML -user "scott/tiger" -fileName "/tmp/temp.xml" "emp"
This performs the following tasks:
emp
table
Table 8-2 lists the putXML
options:
The following two classes make up the XML SQL Utility Java API:
oracle.xml.sql.query.OracleXMLQuery
save
, insert
, update
, and delete
: oracle.xml.sql.dml.OracleXMLSave
The OracleXMLQuery
class makes up the XML generation part of the XSU Java API. Figure 8-4 illustrates the basic steps you need to take when using OracleXMLQuery to generate XML:
OracleXMLQuery
instance by supplying an SQL string or a ResultSet
object.The following examples illustrate how XSU can generate an XML document in its DOM or string representation given a SQL query. See Figure 8-5.
Before generating the XML you must create a connection to the database. The connection can be obtained by supplying the JDBC connect string. First register the Oracle JDBC class and then create the connection, as follows
// import the Oracle driver.. import oracle.jdbc.driver.*; // Load the Oracle JDBC driver DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); // Create the connection. Connection conn = DriverManager.getConnection("jdbc:oracle:oci8:@","scott","tiger");
Here, the connection is done using OCI8's JDBC driver. You can connect to the scott
schema supplying the password tiger
. It connects to the current database (identified by the ORA_SID
environment variable). You can also use the JDBC thin driver to connect to the database. The thin driver is written in pure Java and can be called from within applets or any other Java program.
See Also::
Oracle9i Java Developer's Guide for more details. |
// Create the connection. Connection conn = DriverManager.getConnection("jdbc:oracle:thin:@dlsun489:1521:ORCL",
"scott","tiger");
The thin driver requires you to specify the host name (dlsun489), port number (1521), and the Oracle SID (ORCL), which identifies a specific Oracle instance on the machine.
defaultConnection()
on the oracle.jdbc.driver.OracleDriver()
class to get the current connection, as follows:
import oracle.jdbc.driver.*; // Load the Oracle JDBC driver DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); Connection conn = new oracle.jdbc.driver.OracleDriver ().defaultConnection ();
The remaining discussion either assumes you are using an OCI8 connection from the client or that you already have a connection object created. Use the appropriate connection creation based on your needs.
Once you have registered your connection, create an OracleXMLQuery
class instance by supplying a SQL query to execute as follows:
// import the query class in to your class import oracle.xml.sql.query.OracleXMLQuery; OracleXMLQuery qry = new OracleXMLQuery (conn, "select * from emp");
You are now ready to use the query class.
Here is a complete listing of the program to extract (generate) the XML string. This program gets the string and prints it out to standard output:
import oracle.jdbc.driver.*; import oracle.xml.sql.query.OracleXMLQuery; import java.lang.*; import java.sql.*; // class to test the String generation! class testXMLSQL { public static void main(String[] argv) { try{ // create the connection Connection conn = getConnection("scott","tiger"); // Create the query class. OracleXMLQuery qry = new OracleXMLQuery(conn, "select * from emp"); // Get the XML string String str = qry.getXMLString(); // Print the XML output System.out.println(" The XML output is:\n"+str); // Always close the query to get rid of any resources.. qry.close(); }catch(SQLException e){ System.out.println(e.toString()); } } // Get the connection given the user name and password..! private static Connection getConnection(String username, String password) throws SQLException { // register the JDBC driver.. DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); // Create the connection using the OCI8 driver Connection conn = DriverManager.getConnection("jdbc:oracle:oci8:@",username,password); return conn; } }
To run this program, carry out the following:
testXMLSQL.java
javac
, the Java compilerjava testXMLSQL
You must have the CLASSPATH
pointing to this directory for the Java executable to find the class. Alternatively use various visual Java tools including Oracle JDeveloper to compile and run this program. When run, this program prints out the XML file to the screen.
DOM (Document Object Model) is a standard defined by the W3C committee. DOM represents an XML document in a parsed tree-like form. Each XML entity becomes a DOM node. Thus XML elements and attributes become DOM nodes while their children become child nodes. To generate a DOM tree from the XML generated by XSU, you can directly request a DOM document from XSU, as it saves the overhead of having to create a string representation of the XML document and then parse it to generate the DOM tree.
XSU calls the parser to directly construct the DOM tree from the data values. The following example illustrates how to generate a DOM tree. The example steps through the DOM tree and prints all the nodes one by one.
import org.w3c.dom.*; import oracle.xml.parser.v2.*; import java.sql.*; import oracle.xml.sql.query.OracleXMLQuery; import java.io.*; class domTest{ public static void main(String[] argv) { try{ // create the connection Connection conn = getConnection("scott","tiger"); // Create the query class. OracleXMLQuery qry = new OracleXMLQuery(conn, "select * from emp"); // Get the XML DOM object. The actual type is the Oracle Parser's DOM // representation. (XMLDocument) XMLDocument domDoc = (XMLDocument)qry.getXMLDOM(); // Print the XML output directly from the DOM domDoc.print(System.out); // If you instead want to print it to a string buffer you can do this..! StringWriter s = new StringWriter(10000); domDoc.print(new PrintWriter(s)); System.out.println(" The string version ---> "+s.toString()); qry.close(); // You should always close the query!! }catch(Exception e){ System.out.println(e.toString()); } } // Get the connection given the user name and password..! private static Connection getConnection(String user, String passwd) throws SQLException { DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); Connection conn = DriverManager.getConnection("jdbc:oracle:oci8:@",user,passwd); return conn; } }
In the examples shown so far, XML SQL Utility (XSU) takes the ResultSet or the query and generates the whole document from all the rows of the query. To obtain 100 rows at a time, you would then have to fire off different queries to get the first 100 rows, the next 100, and so on. Also it is not possible to skip the first five rows of the query and then generate the result.
To obtain the desired results, use the XSU skipRows
and maxRows
parameter settings:
skipRows
parameter, when set, forces the generation to skip the desired number of rows before starting to generate the result.maxRows
limits the number of rows converted to XML.For example, if you set skipRows
to a value of 5 and maxRows
to a value of 10, then XSU skips the first 5 rows, then generates XML for the next 10 rows.
In Web scenarios, you may want to keep the query object open for the duration of the user's session. For example, consider the case of a Web search engine which gives the results of a user's search in a paginated fashion. The first page lists 10 results, the next page lists 10 more results, and so on.
To achieve this, request XSU to convert 10 rows at a time and keep the ResultSet state active, so that the next time you ask XSU for more results, it starts generating from the place the last generation finished. See "XSU Generating XML Example 3: Paginating Results: Generating an XML Page (Java)" .
There is also the case when the number of rows, or number of columns in a row are very large. In this case, you can generate multiple documents each of a smaller size.
These cases can be handled by using the maxRows
parameter and the keepObjectOpen
function.
Typically, as soon as all results are generated, OracleXMLQuery
internally closes the ResultSet
, if it created one using the SQL query string given, since it assumes you no longer want any more results. However, in the case described earlier, to maintain that state, you need to call the keepObjectOpen
function to keep the cursor active. See the following example.
This example, writes a simple class that maintains the state and generates the next page each time it is called.
import org.w3c.dom.*; import oracle.xml.parser.v2.*; import java.sql.*; import oracle.xml.sql.query.OracleXMLQuery; import java.io.*; public class pageTest { Connection conn; OracleXMLQuery qry; ResultSet rset; Statement stmt; int lastRow = 0; public pageTest(String sqlQuery) { try{ conn = getConnection("scott","tiger"); //stmt = conn.createStatement(ResultSet.TYPE_SCROLL_SENSITIVE, // ResultSet.CONCUR_READ_ONLY);// create a scrollable Rset //stmt = conn.createStatement(ResultSet.TYPE_SCROLL_INSENSITIVE, // ResultSet.CONCUR_READ_ONLY);// create a scrollable Rset stmt = conn.createStatement(); ResultSet rset = stmt.executeQuery(sqlQuery); // get the result set.. rset.first(); qry = new OracleXMLQuery(conn,rset); // create a OracleXMLQuery instance qry.keepCursorState(true); // Don't lose state after the first fetch qry.setRaiseNoRowsException(true); qry.setRaiseException(true); }catch(SQLException e){ System.out.println(e.toString()); } } // Returns the next XML page..! public String getResult(int startRow, int endRow) throws SQLException { //rset.relative(lastRow-startRow); // scroll inside the result set //rset.absolute(startRow); // scroll inside the result set qry.setMaxRows(endRow-startRow); // set the max # of rows to retrieve..! //System.out.println("before getxml"); return qry.getXMLString(); } // Function to still perform the next page. public String nextPage() throws SQLException { String result = getResult(lastRow,lastRow+10); lastRow+= 10; return result; } public void close() throws SQLException { stmt.close(); // close the statement.. conn.close(); // close the connection qry.close(); // close the query.. } public static void main(String[] argv) { String str; try{ pageTest test = new pageTest("select e.* from emp e"); int i = 0; // Get the data one page at a time..!!!!! while ((str = test.getResult(i,i+10))!= null) { System.out.println(str); i+= 10; } test.close(); }catch(Exception e){ e.printStackTrace(System.out); } } // Get the connection given the user name and password..! private static Connection getConnection(String user, String passwd) throws SQLException { DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); Connection conn = DriverManager.getConnection("jdbc:oracle:oci8:@",user,passwd); return conn; } }
You saw how you can supply a SQL query and get the results as XML. In the last example, you retrieved paginated results. However in Web cases, you may want to retrieve the previous page and not just the next page of results. To provide this scrollable functionality, you can use the Scrollable ResultSet
. Use the ResultSet
object to move back and forth within the result set and use XSU to generate the XML each time. The following example illustrates how to do this.
This example shows you how to use the JDBC ResultSet
to generate XML. Note that using the ResultSet
might be necessary in cases that are not handled directly by XSU, for example, when setting the batch size, binding values, and so on. This example extends the previously defined pageTest
class to handle any page.
public class pageTest() { Connection conn; OracleXMLQuery qry; ResultSet rset; int lastRow = 0; public pageTest(String sqlQuery) { conn = getConnection("scott","tiger"); Statement stmt = conn.createStatement(sqlQuery);// create a scrollable Rset ResultSet rset = stmt.executeQuery(); // get the result set.. qry = new OracleXMLQuery(conn,rset); // create a OracleXMLQuery instance qry.keepObjectOpen(true); // Don't lose state after the first fetch } // Returns the next XML page..! public String getResult(int startRow, int endRow) { rset.scroll(lastRow-startRow); // scroll inside the result set qry.setMaxRows(endRow-startRow); // set the max # of rows to retrieve..! return qry.getXMLString(); } // Function to still perform the next page. public String nextPage() { String result = getResult(lastRow,lastRow+10); lastRow+= 10; return result; } public void close() { stmt.close(); // close the statement.. conn.close(); // close the connection qry.close(); // close the query.. } public void main(String[] argv) { pageTest test = new pageTest("select * from emp"); int i = 0; // Get the data one page at a time..!!!!! while ((str = test.getResult(i,i+10))!= null) { System.out.println(str); i+= 10; } test.close(); } }
The OracleXMLQuery
class provides XML conversion only for query strings or ResultSets
. But in your application if you have PL/SQL procedures that return REF cursors, how would you do the conversion?
In this case, you can use the earlier-mentioned ResultSet conversion mechanism to perform the task. REF cursors are references to cursor objects in PL/SQL. These cursor objects are valid SQL statements that can be iterated upon to get a set of values. These REF cursors are converted into OracleResultSet
objects in the Java world.
You can execute these procedures, get the OracleResultSet
object, and then send that to the OracleXMLQuery
object to get the desired XML.
Consider the following PL/SQL function that defines a REF cursor and returns it:
CREATE OR REPLACE package body testRef is function testRefCur RETURN empREF is a empREF; begin OPEN a FOR select * from scott.emp; return a; end; end; /
Every time this function is called, it opens a cursor object for the query, select * from emp
and returns that cursor instance. To convert this to XML, you can do the following:
import org.w3c.dom.*; import oracle.xml.parser.v2.*; import java.sql.*; import oracle.jdbc.driver.*; import oracle.xml.sql.query.OracleXMLQuery; import java.io.*; public class REFCURtest { public static void main(String[] argv) throws SQLException { String str; Connection conn = getConnection("scott","tiger"); // create connection // Create a ResultSet object by calling the PL/SQL function CallableStatement stmt = conn.prepareCall("begin ? := testRef.testRefCur(); end;"); stmt.registerOutParameter(1,OracleTypes.CURSOR); // set the define type stmt.execute(); // Execute the statement. ResultSet rset = (ResultSet)stmt.getObject(1); // Get the ResultSet OracleXMLQuery qry = new OracleXMLQuery(conn,rset); // prepare Query class qry.setRaiseNoRowsException(true); qry.setRaiseException(true); qry.keepCursorState(true); // set options (keep the cursor active. while ((str = qry.getXMLString())!= null) System.out.println(str); qry.close(); // close the query..! // Note since we supplied the statement and resultset, closing the // OracleXMLquery instance will not close these. We would need to // explicitly close this ourselves..! stmt.close(); conn.close(); } // Get the connection given the user name and password..! private static Connection getConnection(String user, String passwd) throws SQLException { DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); Connection conn = DriverManager.getConnection("jdbc:oracle:oci8:@",user,passwd); return conn; } }
To apply the stylesheet, on the other hand, use the applyStylesheet()
command. This forces the stylesheet to be applied before generating the output.
When there are no rows to process, XSU simply returns a null string. However, it might be desirable to get an exception every time there are no more rows present, so that the application can process this through exception handlers. When the setRaiseNoRowsException
() is set, then whenever there are no rows to generate for the output XSU raises an oracle.xml.sql.OracleXMLSQLNoRowsException
. This is a run time exception and need not be caught unless needed.
The following code extends the previous examples to use the exception instead of checking for null strings:
public class pageTest { .... // rest of the class definitions.... public void main(String[] argv) { pageTest test = new pageTest("select * from emp"); test.query.setRaiseNoRowsException(true); // ask it to generate exceptions try { while(true) System.out.println(test.nextPage()); } catch(oracle.xml.sql.OracleXMLNoRowsException) { System.out.println(" END OF OUTPUT "); test.close(); } } }
Note: Notice how the condition to check the termination changed from checking for the result to be |
Now that you have seen how queries can be converted to XML, observe how you can put the XML back into the tables or views using XSU. The class oracle.xml.sql.dml.OracleXMLSave
provides this functionality. It has methods to insert XML into tables, update existing tables with the XML document, and delete rows from the table based on XML element values.
In all these cases the given XML document is parsed, and the elements are examined to match tag names to column names in the target table or view. The elements are converted to the SQL types and then bound to the appropriate statement. The process for storing XML using XSU is shown in Figure 8-6.
Consider an XML document that contains a list of ROW elements, each of which constitutes a separate DML operation, namely, insert
, update,
or delete
on the table or view.
To insert a document into a table or view, simply supply the table or the view name and then the document. XSU parses the document (if a string is given) and then creates an INSERT
statement into which it binds all the values. By default, XSU inserts values into all the columns of the table or view and an absent element is treated as a NULL
value. The following example shows you how the XML document generated from the emp
table, can be stored in the table with relative ease.
This example inserts XML values into all columns:
// This program takes as an argument the file name, or a url to // a properly formated XML document and inserts it into the SCOTT.EMP table. import java.sql.*; import oracle.xml.sql.dml.OracleXMLSave; public class testInsert { public static void main(String argv[]) throws SQLException { DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); Connection conn = DriverManager.getConnection("jdbc:oracle:oci8:@","scott","tiger"); OracleXMLSave sav = new OracleXMLSave(conn, "emp"); sav.insertXML(sav.getUrl(argv[0])); sav.close(); } }
An INSERT
statement of the form:
insert into scott.emp (EMPNO, ENAME, JOB, MGR, SAL, DEPTNO) VALUES(?,?,?,?,?,?);
is generated, and the element tags in the input XML document matching the column names are matched and their values bound.
If you store the following XML document:
<?xml version='1.0'?> <ROWSET> <ROW num="1"> <EMPNO>7369</EMPNO> <ENAME>Smith</ENAME> <JOB>CLERK</JOB> <MGR>7902</MGR> <HIREDATE>12/17/1980 0:0:0</HIREDATE> <SAL>800</SAL> <DEPTNO>20</DEPTNO> </ROW> <!-- additional rows ... --> </ROWSET>
to a file and specify the file to the program described earlier, you would end up with a new row in the emp
table containing the values (7369, Smith, CLERK, 7902, 12/17/1980,800,20
). Any element absent inside the row element is taken as a null value.
In certain cases, you may not want to insert values into all columns. This may be true when the group of values that you are getting is not the complete set and you need triggers or default values to be used for the rest of the columns. The code following shows how this can be done.
Assume that you are getting the values only for the employee number, name, and job and that the salary, manager, department number, and hire date fields are filled in automatically. First create a list of column names that you want the insert
to work on and then pass it to the OracleXMLSave
instance.
import java.sql.*; import oracle.xml.sql.dml.OracleXMLSave; public class testInsert { public static void main(String argv[]) throws SQLException { Connection conn = getConnection("scott","tiger"); OracleXMLSave sav = new OracleXMLSave(conn, "scott.emp"); String [] colNames = new String[5]; colNames[0] = "EMPNO"; colNames[1] = "ENAME"; colNames[2] = "JOB"; sav.setUpdateColumnList(colNames); // set the columns to update..! // Assume that the user passes in this document as the first argument! sav.insertXML(argv[0]); sav.close(); } // Get the connection given the user name and password..! private static Connection getConnection(String user, String passwd) throws SQLException { DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); Connection conn = DriverManager.getConnection("jdbc:oracle:oci8:@",user,passwd); return conn; } }
An insert
statement of the form:
insert into scott.emp (EMPNO, ENAME, JOB) VALUES (?, ?, ?);
is generated. Note that, in the preceding example, if the inserted document contains values for the other columns (JOB, HIREDATE
, and so on), those are ignored. Also an insert
is performed for each ROW
element that is present in the input. These inserts are batched by default.
Now that you know how to insert values into the table from XML documents, see how you can update only certain values. In an XML document, to update the salary of an employee and the department that they work in:
<ROWSET> <ROW num="1"> <EMPNO>7369</EMPNO> <SAL>1800</SAL> <DEPTNO>30</DEPTNO> </ROW> <ROW> <EMPNO>2290</EMPNO> <SAL>2000</SAL> <HIREDATE>12/31/1992</HIREDATE> <!-- additional rows ... --> </ROWSET>
You can use the XSU to update the values. For updates, you must supply XSU with the list of key column names. These form part of the WHERE
clause in the UPDATE
statement. In the emp
table shown earlier, employee number (EMPNO
) column forms the key. Use this for updates.
This example updates table
, emp
, using keyColumns
:
import java.sql.*; import oracle.xml.sql.dml.OracleXMLSave; public class testUpdate { public static void main(String argv[]) throws SQLException { Connection conn = getConnection("scott","tiger"); OracleXMLSave sav = new OracleXMLSave(conn, "scott.emp"); String [] keyColNames = new String[1]; keyColNames[0] = "EMPNO"; sav.setKeyColumnList(keyColNames); // Assume that the user passes in this document as the first argument! sav.updateXML(argv[0]); sav.close(); } // Get the connection given the user name and password..! private static Connection getConnection(String user, String passwd) throws SQLException { DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); Connection conn = DriverManager.getConnection("jdbc:oracle:oci8:@",user,passwd); return conn; } }
In this example, two UPDATE
statements are generated. For the first ROW
element, you generate an UPDATE
statement to update the SAL
and JOB
fields as follows:
update scott.emp SET SAL = 1800 and DEPTNO = 30 WHERE EMPNO = 7369;
For the second ROW
element:
update scott.emp SET SAL = 2000 and HIREDATE = 12/31/1992 WHERE EMPNO = 2290;
You may want to specify a list of columns to update. This would speed up the processing since the same UPDATE
statement can be used for all the ROW
elements. Also you can ignore other tags in the XML document.
Note: When you specify a list of columns to update, an element corresponding to one of the update columns, if absent, will be treated as |
If you know that all the elements to be updated are the same for all the ROW
elements in the XML document, you can use the setUpdateColumnNames
() function to set the list of columns to update.
import java.sql.*; import oracle.xml.sql.dml.OracleXMLSave; public class testUpdate { public static void main(String argv[]) throws SQLException { Connection conn = getConnection("scott","tiger"); OracleXMLSave sav = new OracleXMLSave(conn, "scott.emp"); String [] keyColNames = new String[1]; keyColNames[0] = "EMPNO"; sav.setKeyColumnList(keyColNames); // you create the list of columns to update..! // Note that if you do not supply this, then for each ROW element in the // XML document, you would generate a new update statement to update all // the tag values (other than the key columns)present in that element. String[] updateColNames = new String[2]; updateColNames[0] = "SAL"; updateColNames[1] = "JOB"; sav.setUpdateColumnList(updateColNames); // set the columns to update..! // Assume that the user passes in this document as the first argument! sav.updateXML(argv[0]); sav.close(); } // Get the connection given the user name and password..! private static Connection getConnection(String user, String passwd) throws SQLException { DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); Connection conn = DriverManager.getConnection("jdbc:oracle:oci8:@",user,passwd); return conn; } }
When deleting from XML documents, you can set the list of key columns. These columns are used in the WHERE
clause of the DELETE
statement. If the key column names are not supplied, then a new DELETE
statement is created for each ROW
element of the XML document, where the list of columns in the WHERE
clause of the DELETE
statement will match those in the ROW element.
Consider this delete example:
import java.sql.*; import oracle.xml.sql.dml.OracleXMLSave; public class testDelete { public static void main(String argv[]) throws SQLException { Connection conn = getConnection("scott","tiger"); OracleXMLSave sav = new OracleXMLSave(conn, "scott.emp"); // Assume that the user passes in this document as the first argument! sav.deleteXML(argv[0]); sav.close(); } // Get the connection given the user name and password..! private static Connection getConnection(String user, String passwd) throws SQLException { DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); Connection conn = DriverManager.getConnection("jdbc:oracle:oci8:@",user,passwd); return conn; } }
Using the same XML document shown previously for the update example, you would end up with two DELETE
statements:
DELETE FROM scott.emp WHERE empno=7369 and sal=1800 and deptno=30; DELETE FROM scott.emp WHERE empno=2200 and sal=2000 and hiredate=12/31/1992;
The DELETE
statements were formed based on the tag names present in each ROW
element in the XML document.
If instead, you want the DELETE
statement to only use the key values as predicates, you can use the setKeyColumn
function to set this.
import java.sql.*; import oracle.xml.sql.dml.OracleXMLSave; public class testDelete { public static void main(String argv[]) throws SQLException { Connection conn = getConnection("scott","tiger"); OracleXMLSave sav = new OracleXMLSave(conn, "scott.emp"); String [] keyColNames = new String[1]; keyColNames[0] = "EMPNO"; sav.setKeyColumnList(keyColNames); // Assume that the user passes in this document as the first argument! sav.deleteXML(argv[0]); sav.close(); } // Get the connection given the user name and password..! private static Connection getConnection(String user, String passwd) throws SQLException { DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); Connection conn = DriverManager.getConnection("jdbc:oracle:oci8:@",user,passwd); return conn; } }
Here is a single DELETE
statement of the form:
DELETE FROM scott.emp WHERE EMPNO=?
XSU catches all exceptions that occur during processing and throws an oracle.xml.sql.OracleXMLSQLException
which is a run time exception. The calling program thus does not have to catch this exception all the time, if the program can still catch this exception and do the appropriate action. The exception class provides functions to get the error message and also get the parent exception, if any. For example, the program shown later, catches the run time exception and then gets the parent exception.
This exception is generated when the setRaiseNoRowsException
is set in the OracleXMLQuery
class during generation. This is a subclass of the OracleXMLSQLException
class and can be used as an indicator of the end of row processing during generation.
import java.sql.*; import oracle.xml.sql.query.OracleXMLQuery; public class testException { public static void main(String argv[]) throws SQLException { Connection conn = getConnection("scott","tiger"); // wrong query this will generate an exception OracleXMLQuery qry = new OracleXMLQuery(conn, "select * from emp where sd = 322323"); qry.setRaiseException(true); // ask it to raise exceptions..! try{ String str = qry.getXMLString(); }catch(oracle.xml.sql.OracleXMLSQLException e) { // Get the original exception Exception parent = e.getParentException(); if (parent instanceof java.sql.SQLException) { // perform some other stuff. Here you simply print it out.. System.out.println(" Caught SQL Exception:"+parent.getMessage()); } else System.out.println(" Exception caught..!"+e.getMessage()); } } // Get the connection given the user name and password..! private static Connection getConnection(String user, String passwd) throws SQLException { DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); Connection conn = DriverManager.getConnection("jdbc:oracle:oci8:@",user,passwd); return conn; }
}
This section lists XML SQL Utility (XSU) questions and answers.
I have the following XML in my customer.xml
file:
<ROWSET> <ROW num="1"> <CUSTOMER> <CUSTOMERID>1044</CUSTOMERID> <FIRSTNAME>Paul</FIRSTNAME> <LASTNAME>Astoria</LASTNAME> <HOMEADDRESS> <STREET>123 Cherry Lane</STREET> <CITY>SF</CITY> <STATE>CA</STATE> <ZIP>94132</ZIP> </HOMEADDRESS> </CUSTOMER> </ROW> </ROWSET>
What database schema structure should I use to store this XML with XSU?
Answer: Since your example is more than one level deep (that is, it has a nested structure), you should use an object-relational schema. The XML preceding will canonically map to such a schema. An appropriate database schema would be the following:
create type address_type as object ( street varchar2(40), city varchar2(20), state varchar2(10), zip varchar2(10) ); / create type customer_type as object ( customerid number(10), firstname varchar2(20), lastname varchar2(20), homeaddress address_type ); / create table customer_tab ( customer customer_type);
In the case you wanted to load customer.xml
by means of XSU into a relational schema, you can still do it by creating objects in views on top of your relational schema.
For example, you would have a relational table which would contain all the following information:
create table cust_tab ( customerid number(10), firstname varchar2(20), lastname varchar2(20), state varchar2(40), city varchar2(20), state varchar2(20), zip varchar2(20) );
Then, you would create a customer view which contains a customer object on top of it, as in the following example:
create view customer_view as select customer_type(customerid, firstname, lastname, address_type(state,street,city,zip)) from cust_tab;
Finally, you can flatten your XML using XSLT and then insert it directly into your relational schema. However, this is the least recommended option.
Answer: Currently the XML SQL Utility (XSU) can only store data in a single table. It maps a canonical representation of an XML document into any table or view. But there is a way to store XML with XSU across tables. One can do this using XSLT to transform any document into multiple documents and insert them separately. Another way is to define views over multiple tables (using object views if needed) and then do the inserts
into the view. If the view is inherently non-updatable (because of complex joins), then you can use INSTEAD OF
triggers over the views to do the inserts.
I would like to use XSU to load XML where some of the data is stored in attributes. However, XSU seems to ignore the XML attributes. What can I do?
Answer: Unfortunately, for now you will have to use XSLT to transform your XML document; that is, you must change the attributes into elements. XSU does assume canonical mapping from XML to a database schema. This takes away a bit from the flexibility, forcing you to sometimes resort to XSLT, but at the same time, in the common case, it does not burden you with having to specify a mapping.
I am trying to insert the following XML document (dual.xml
):
<ROWSET> <row> <DUMMY>X</DUMMY> </row> </ROWSET>
Into the table dual
using the command line front end of the XSU, like in this example:
java OracleXML putxml -filename dual.xml dual
I get the following error:
oracle.xml.sql.OracleXMLSQLException: No rows to modify -- the row enclosing tag missing. Specify the correct row enclosing tag.
Answer: By default, XSU is case sensitive, so it looks for the record separator tag which by default is ROW
, yet all it can find is row
. Another common, related mistake is to mismatch the case of one of the element tags. For example, if in dual.xml
the tag DUMMY
was actually dummy
, then XSU raises an error stating that it could not find a matching column in table, dual
. So you have two options: use the correct case or use the ignoreCase
feature.
Answer: No. Due to a number of shortcomings of the DTD, this functionality is not available. The W3C XML Schema recommendation is finalized, but this functionality is not available yet in XSU.
I am using the XML SQL Utility command line front end, and I am passing a connect string but I get a TNS error. Can you provide examples of a thin driver connect string and an OCI8 driver connect string?
Answer: An example of an JDBC thin driver connect string is:
jdbc:oracle:thin:<user>/<password>@<hostname>:<port number>:<DB SID>;
Furthermore, the database must have an active TCP/IP listener. A valid OCI8 connect string would be:
jdbc:oracle:oci8:<user>/<password>@<hostname>
Does XML SQL Utility commit after it is done inserting, deleting, or updating? What happens if an error occurs?
Answer: By default the XSU executes a number of insert
, delete
, or update
statements at a time. The number of statements batch together and executed at the same time can be overridden using the setBatchSize
feature.
Also, by default XSU does no explicit commits. If autocommit is on (default for the JDBC connection), then after each batch of statement executions a commit occurs. You can override this by turning autocommit off and then specifying after how many statement executions a commit should occur, which can be done using the setCommitBatch
feature.
If an error occurs, XSU rolls back to either the state the target table was in before the particular call to XSU, or the state right after the last commit made during the current call to XSU.
Can you explain how to map table columns to XML attributes using XSU?
Answer: From XSU release 2.1.0 you can map a particular column or a group of columns to an XML attribute instead of an XML element. To achieve this, you have to create an alias for the column name, and prepend the at sign (@) to the name of this alias. For example:
* Create a file called select.sql with the following content : SELECT empno "@EMPNO", ename, job, hiredate FROM emp ORDER BY empno * Call the XML SQL Utility : java OracleXML getXML -user "scott/tiger" \ -conn "jdbc:oracle:thin:@myhost:1521:ORCL" \ -fileName "select.sql" * As a result, the XML document will look like : <?xml version = '1.0'?> <ROWSET> <ROW num="1" EMPNO="7369"> <ENAME>SMITH</ENAME> <JOB>CLERK</JOB> <HIREDATE>12/17/1980 0:0:0</HIREDATE> </ROW> <ROW num="2" EMPNO="7499"> <ENAME>ALLEN</ENAME> <JOB>SALESMAN</JOB> <HIREDATE>2/20/1981 0:0:0</HIREDATE> </ROW> </ROWSET>
Since the XML document is created in a streamed manner, the following query:
SELECT ename, empno "@EMPNO", ...
would not generate the expected result. It is currently not possible to load XML data stored in attributes. You will still need to use an XSLT transformation to change the attributes into elements. XSU assumes canonical mapping from XML to a database schema.
|
Copyright © 2001, 2002 Oracle Corporation. All Rights Reserved. |
|