With 7.1, you can create XML columns, insert XML values, publish XML values, and so much more.
XML has become the standard for document and data interchange on the Internet and is a key technology in the support for service-oriented architecture (SOA). This open standard allows the interchange of data between closed-architecture and open-architecture data management systems. Its use in SQL has been standardized by the SQL/XML standards and has become an ISO and ANSI standard. IBM has added many features for using XML within SQL in the 7.1 release for IBM i.
Moving XML into the database provides applications with database reliability and scalability, as well as the strong data management and security capabilities of the database, and places XML documents under the transaction control of the database. The SQL XML capabilities added in 7.1 replaces many of the features previously available only with the XML Extender licensed program.
Introduction to XML in SQL
XML capabilities have been added to perform many common SQL operations with XML data, including the following:
- Creating tables with XML columns
- Adding XML columns to existing tables
- Inserting, updating, or deleting XML documents
- Creating views with XML columns
- Creating triggers on tables with XML columns
- Passing XML values to procedures and functions
- Decomposing XML documents into SQL tables with annotated decomposition
- Publishing relational data as XML values
The XML data type is now a first-class data type for DB2 for i, just like the existing character, graphic, and LOB data types. It can be specified in the SQL CREATE TABLE statement:
CREATE TABLE AuthorInfo (AuthorID BIGINT NOT NULL, RegistrationInfo XML);
SQL tables can contain any combination of XML and relational columns, and applications can access both existing relational columns and XML data in the same SQL statement. A column of the XML data type holds one well-formed XML document for each row in the table. An XML schema is not required to define an XML column and to store well-formed XML documents. The well-formed document parsing is enforced on the insert.
Schema validation can optionally be specified on a per-document basis:
EXEC SQL INSERT INTO AuthorInfo (RegistrationInfo)
VALUES(XMLVALIDATE(XMLPARSE(document '<?xml version="1.0"?>
<auth:author xmlns:auth="http://www.testcase.com/normalization"
xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
xsi:schemaLocation="http://www.testcase.com/schemahint.xsd"
ID=" 22">
<firstname>Ann</firstname>
<lastname> Brown </lastname>
<activeStatus>1</activeStatus>
</auth:author>' preserve whitespace)
ACCORDING TO XMLSCHEMA ID APPSCHEMA.AUTHINFO));
A registered XML schema is required to store validated XML documents. The XML schema defines the valid content for inserted documents.
Unlike character types, the XML data type has no length specified. However, the XML data type is limited to a 2 GB maximum length.
The XML data type can be specified as a column type and also as a data type for host variables in embedded SQL RPG and C programs, for example, and can be specified in Java programs, as well as for parameter markers in dynamic SQL statements. A CCSID can be specified for the XML column, but all XML parsing is performed in Unicode UTF-8. Unicode UTF-8 should be considered for performance and interoperability with other server systems. XML cannot be specified in a DDS specification.
The XML Schema Repository
The XML schema repository consists of the new *SQLXSR object type and the new SQL catalogs for cataloging the registered XML schemas. Don't confuse an XML schema with the SQL schema, which qualifies object names such as tables, views, indexes, and triggers. An XML schema is specified in an .xsd document and is registered with an SQL schema, an SQL name, a URL that specifies the schema location, and the primary namespace of the documents to be validated:
EXEC SQL CALL SYSPROC.XSR_REGISTER('APPSCHEMA', 'AUTHINFO',
:schemalocation:
The :schemalocation host variable contains the schema location, and :hvblob is the .xsd document source.
The XML schema repository is also used for XML schema-based annotated decomposition. The registered XML schemas are stored in a binary representation for fast schema validation and annotated decomposition.
The XML schemas are registered using a set of built-in stored procedures:
XML Schema Registration |
|
XSR_REGISTER |
Called first to register the XML schema with the XSR |
XSR_ADDSCHEMADOC |
Adds additional schema documents to the primary document |
XSR_COMPLETE |
Called to complete the registration and update the catalogs |
XSR objects can be removed with the SQL DROP XSROBJECT statement or with the XSR_REMOVE built-in procedure. The XSR built-in procedures are defined in the SYSPROC SQL schema. The .xsd files can be edited with a schema editor, such as the one found in the Eclipse tool set.
Inserting XML Values: Digging Deeper
Quite often, XML values will originate from files stored in an IFS directory. The XML value can be inserted into the table column from an SQL file reference variable in embedded SQL:
SQL TYPE IS XML AS CLOB_FILE :frv;
short int frvind;
frv.name_length = strlen("/tmp/data/docdata.xml");
frv.data_length = 0;
frv.file_options = SQL_FILE_READ;
(void)strcpy(frv.name, "/tmp/data/docdata.xml");
frvind = 0;
EXEC SQL INSERT INTO APPDATA(DOC) VALUES(:frv:frvind);
But some additional built-in functions were added in the 7.1 release to conveniently handle this file input:
INSERT INTO CUSTOMERTABLE(DOC) VALUES(GET_XML_FILE('/tmp/data/customer.xml'));
The GET_BLOB_FROM_FILE, GET_CLOB_FROM_FILE, GET_DBCLOB_FROM_FILE, and GET_XML_FILE built-in functions can also be specified in dynamic SQL and in RUNSQLSTM.
For SQL UPDATE, the update is always a full document replace.
Retrieving XML Values
When an application fetches an XML value from a query result set, the XML value is serialized into the application variable. An XML declaration precedes the XML value. The XML declaration is the following string, where the encoding-name matches the CCSID of the result data type:
'
XML values are "implicitly" serialized into application variables when specified on the SQL FETCH or SELECT INTO statement. The XMLSERIALIZE built-in function may need to be specified when you're casting to a different data type or a CCSID conversion is required.
XML in Procedure and Function Parameters
The XML data type is allowed for parameters in SQL procedures and functions. It is also allowed for parameters in external procedures and functions written for RPG, C, and other programming languages.
The XML data type is specified on the parameter declaration:
CREATE PROCEDURE MakeXMLElement (IN p1 INT, OUT p2 XML)
LANGUAGE SQL
BEGIN
VALUES XMLELEMENT(NAME "AppValue", p1) INTO p2;
END;
For this example, an INTEGER input value and an XML result value would be specified on the SQL CALL statement. Note that the XML type cannot be implicitly cast to CHARACTER or GRAPHIC data types. Check the SQL Reference for the supported casts between built-in data types.
For external procedures and functions, the XML type is specified along with an XML AS cast type. The XML cast type specification is required because the XML type cannot be declared directly in programming languages:
CREATE FUNCTION MyXMLFunction(P1 XML AS CLOB(2K)) RETURNS BLOB(2K)
LANGUAGE C IS DETERMINISTIC MODIFIES SQL DATA
EXTERNAL NAME 'MYLIB/MYCODE(XMLFUNC1)'
PARAMETER STYLE SQL
FENCED;
The embedded SQL TYPE IS statement declares a host variable of the XML type to receive the input XML value or to return an XML value from an external function:
SQL TYPE IS XML AS CLOB(100) appvar1;
Querying XML Values
An application has multiple choices for querying stored XML documents. Individual XML elements and attributes can be decomposed into relational columns when the document is stored into the database. Since an SQL index cannot be built on an XML column, building indexes on decomposed relational columns will provide the best application performance. The Omnifind Text Search Server for DB2 for i text-search indexing with the XPath expressions in the SQL CONTAINS built-in function provides XML element- and attribute-searching capabilities. The XSLTRANSFORM built-in function provides XSLT capabilities for transforming XML values into other formats, such as HTML, or into other XML documents with new elements or attributes.
Annotated XML Decomposition
"Decomposition" or "shredding" uses an annotated XML schema to process and store XML document elements and attributes in columns of relational tables. The annotations are specified in the .xsd XML schema file. Registering an XML schema for annotated decomposition is specified on the XSR_REGISTER built-in procedure when registering an XML schema document.
The annotated decomposition is specified using the W3C-recommended XML Schema language. To decompose the author element into the relational table LIBRARYBOOKS, the decomposition for the author element is specified in the .xsd XML schema definition:
<?xml version="1.0" encoding="UTF-8"?>
<xs:schema xmlns:xs="http://www.w3.org/2001/XMLSchema"
xmlns:db2-xdb="http://www.ibm.com/xmlns/prod/db2/xdb1">
<xs:annotation>
<xs:appinfo>
<db2-xdb:defaultSQLSchema>"XMPSCHEMA"</db2-xdb:defaultSQLSchema>
</xs:appinfo>
</xs:annotation>
<xs:element>
<xs:complexType>
<xs:sequence>
<xs:element
db2-xdb:rowSet="LIBRARYBOOKS" db2-xdb:column="FIRSTNAME" />
<xs:element
db2-xdb:rowSet="LIBRARYBOOKS" db2-xdb:column="SURNAME"
<xs:element>
<xs:complexType>
<xs:sequence>
<xs:element
db2-xdb:rowSet="LIBRARYBOOKS" db2-xdb:column="FIRSTNAME" />
<xs:element
db2-xdb:rowSet="LIBRARYBOOKS" db2-xdb:column="SURNAME"
db2-xdb:normalization="whitespaceStrip" />
</xs:sequence>
<xs:attribute/>
</xs:complexType>
</xs:element>
</xs:schema>
Following the registration of the XML schema for decomposition, when the SYSPROC.XDBDECOMPXML built-in stored procedure is called with the source XML document shown below, a row is inserted into the LIBRARYBOOKS table, with the author information inserted into the FIRSTNAME and SURNAME columns:
<?xml version="1.0" encoding="UTF-8"?>
<author>
<firstname>Mark</firstname>
<lastname> Twain </lastname>
</author>
Any inserts performed by the decomposition are performed with the isolation level of the caller. Single XML documents can also be decomposed into multiple SQL tables.
XML Publishing Functions
As their name implies, the XML publishing functions, when specified in a query, publish relational data as XML elements, attributes, and XML documents. The use of the XMLFOREST publishing function in the following query shows relational columns being incorporated into an XML result:
SELECT EMPNO AS "Employee Number",
XMLFOREST(XMLNAMESPACES(DEFAULT 'http://hr.org',
'http://mycompany.org' as "empinfo"),
LASTNAME,
FROM EMPLOYEE WHERE EDLEVEL > 12;
XML Publishing Functions for 7.1 |
|
XMLATTRIBUTES |
Constructs XML attributes from the arguments |
XMLCOMMENT |
Returns an XML comment |
XMLCONCAT |
Returns an XML sequence containing the concatenated arguments |
XMLDOCUMENT |
Returns a well-formed XML document |
XMLELEMENT |
Returns an XML element |
XMLFOREST |
Returns a sequence of XML elements |
XMLNAMESPACES |
Constructs a namespace declaration |
XMLPI |
Returns a single processing instruction |
XMLROW |
Returns an XML sequence containing the concatenation of the input XML values. |
XMLTEXT |
Returns a text string |
XMLAGG |
Returns an XML sequence containing the non-null values |
XMLGROUP |
Returns an XML document containing the row elements |
Relational column types, including BINARY, LOB, and XML columns, can be specified in the XML publishing functions.
Creating SQL views containing XML publishing functions provides a powerful and convenient method for publishing XML values to application programs that perform direct I/O.
Final Comments
Using XML in many new 7.1 SQL features has not been explored in this article. Those features include global variables, arrays, and field procedures. Look for information on those topics in upcoming issues of the MC Press Online publications.
LATEST COMMENTS
MC Press Online