Sidebar

Now Introducing XML in SQL on DB2 for IBM i!

SQL
Typography
  • Smaller Small Medium Big Bigger
  • Default Helvetica Segoe Georgia Times

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:ind, :hvblob, null);

 

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, JOB AS "empinfo:job") AS "Employee Info"

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.

Jonathan Triebenbach
Jon Triebenbach is a member of the DB2 for IBM i SQL Data Access team. His previous development projects include SQL triggers and SQL diagnostics. The author can be reached at jlt@us.ibm.com.
BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

RESOURCE CENTER

  • WHITE PAPERS

  • WEBCAST

  • TRIAL SOFTWARE

  • White Paper: Node.js for Enterprise IBM i Modernization

    SB Profound WP 5539

    If your business is thinking about modernizing your legacy IBM i (also known as AS/400 or iSeries) applications, you will want to read this white paper first!

    Download this paper and learn how Node.js can ensure that you:
    - Modernize on-time and budget - no more lengthy, costly, disruptive app rewrites!
    - Retain your IBM i systems of record
    - Find and hire new development talent
    - Integrate new Node.js applications with your existing RPG, Java, .Net, and PHP apps
    - Extend your IBM i capabilties to include Watson API, Cloud, and Internet of Things


    Read Node.js for Enterprise IBM i Modernization Now!

     

  • Profound Logic Solution Guide

    SB Profound WP 5539More than ever, there is a demand for IT to deliver innovation.
    Your IBM i has been an essential part of your business operations for years. However, your organization may struggle to maintain the current system and implement new projects.
    The thousands of customers we've worked with and surveyed state that expectations regarding the digital footprint and vision of the companyare not aligned with the current IT environment.

    Get your copy of this important guide today!

     

  • 2022 IBM i Marketplace Survey Results

    Fortra2022 marks the eighth edition of the IBM i Marketplace Survey Results. Each year, Fortra captures data on how businesses use the IBM i platform and the IT and cybersecurity initiatives it supports.

    Over the years, this survey has become a true industry benchmark, revealing to readers the trends that are shaping and driving the market and providing insight into what the future may bring for this technology.

  • Brunswick bowls a perfect 300 with LANSA!

    FortraBrunswick is the leader in bowling products, services, and industry expertise for the development and renovation of new and existing bowling centers and mixed-use recreation facilities across the entertainment industry. However, the lifeblood of Brunswick’s capital equipment business was running on a 15-year-old software application written in Visual Basic 6 (VB6) with a SQL Server back-end. The application was at the end of its life and needed to be replaced.
    With the help of Visual LANSA, they found an easy-to-use, long-term platform that enabled their team to collaborate, innovate, and integrate with existing systems and databases within a single platform.
    Read the case study to learn how they achieved success and increased the speed of development by 30% with Visual LANSA.

     

  • Progressive Web Apps: Create a Universal Experience Across All Devices

    LANSAProgressive Web Apps allow you to reach anyone, anywhere, and on any device with a single unified codebase. This means that your applications—regardless of browser, device, or platform—instantly become more reliable and consistent. They are the present and future of application development, and more and more businesses are catching on.
    Download this whitepaper and learn:

    • How PWAs support fast application development and streamline DevOps
    • How to give your business a competitive edge using PWAs
    • What makes progressive web apps so versatile, both online and offline

     

     

  • The Power of Coding in a Low-Code Solution

    LANSAWhen it comes to creating your business applications, there are hundreds of coding platforms and programming languages to choose from. These options range from very complex traditional programming languages to Low-Code platforms where sometimes no traditional coding experience is needed.
    Download our whitepaper, The Power of Writing Code in a Low-Code Solution, and:

    • Discover the benefits of Low-code's quick application creation
    • Understand the differences in model-based and language-based Low-Code platforms
    • Explore the strengths of LANSA's Low-Code Solution to Low-Code’s biggest drawbacks

     

     

  • Why Migrate When You Can Modernize?

    LANSABusiness users want new applications now. Market and regulatory pressures require faster application updates and delivery into production. Your IBM i developers may be approaching retirement, and you see no sure way to fill their positions with experienced developers. In addition, you may be caught between maintaining your existing applications and the uncertainty of moving to something new.
    In this white paper, you’ll learn how to think of these issues as opportunities rather than problems. We’ll explore motivations to migrate or modernize, their risks and considerations you should be aware of before embarking on a (migration or modernization) project.
    Lastly, we’ll discuss how modernizing IBM i applications with optimized business workflows, integration with other technologies and new mobile and web user interfaces will enable IT – and the business – to experience time-added value and much more.

     

  • UPDATED: Developer Kit: Making a Business Case for Modernization and Beyond

    Profound Logic Software, Inc.Having trouble getting management approval for modernization projects? The problem may be you're not speaking enough "business" to them.

    This Developer Kit provides you study-backed data and a ready-to-use business case template to help get your very next development project approved!

  • What to Do When Your AS/400 Talent Retires

    FortraIT managers hoping to find new IBM i talent are discovering that the pool of experienced RPG programmers and operators or administrators is small.

    This guide offers strategies and software suggestions to help you plan IT staffing and resources and smooth the transition after your AS/400 talent retires. Read on to learn:

    • Why IBM i skills depletion is a top concern
    • How leading organizations are coping
    • Where automation will make the biggest impact

     

  • Node.js on IBM i Webinar Series Pt. 2: Setting Up Your Development Tools

    Profound Logic Software, Inc.Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application. In Part 2, Brian May teaches you the different tooling options available for writing code, debugging, and using Git for version control. Attend this webinar to learn:

    • Different tools to develop Node.js applications on IBM i
    • Debugging Node.js
    • The basics of Git and tools to help those new to it
    • Using NodeRun.com as a pre-built development environment

     

     

  • Expert Tips for IBM i Security: Beyond the Basics

    SB PowerTech WC GenericIn this session, IBM i security expert Robin Tatam provides a quick recap of IBM i security basics and guides you through some advanced cybersecurity techniques that can help you take data protection to the next level. Robin will cover:

    • Reducing the risk posed by special authorities
    • Establishing object-level security
    • Overseeing user actions and data access

    Don't miss this chance to take your knowledge of IBM i security beyond the basics.

     

     

  • 5 IBM i Security Quick Wins

    SB PowerTech WC GenericIn today’s threat landscape, upper management is laser-focused on cybersecurity. You need to make progress in securing your systems—and make it fast.
    There’s no shortage of actions you could take, but what tactics will actually deliver the results you need? And how can you find a security strategy that fits your budget and time constraints?
    Join top IBM i security expert Robin Tatam as he outlines the five fastest and most impactful changes you can make to strengthen IBM i security this year.
    Your system didn’t become unsecure overnight and you won’t be able to turn it around overnight either. But quick wins are possible with IBM i security, and Robin Tatam will show you how to achieve them.

  • Security Bulletin: Malware Infection Discovered on IBM i Server!

    SB PowerTech WC GenericMalicious programs can bring entire businesses to their knees—and IBM i shops are not immune. It’s critical to grasp the true impact malware can have on IBM i and the network that connects to it. Attend this webinar to gain a thorough understanding of the relationships between:

    • Viruses, native objects, and the integrated file system (IFS)
    • Power Systems and Windows-based viruses and malware
    • PC-based anti-virus scanning versus native IBM i scanning

    There are a number of ways you can minimize your exposure to viruses. IBM i security expert Sandi Moore explains the facts, including how to ensure you're fully protected and compliant with regulations such as PCI.

     

     

  • Encryption on IBM i Simplified

    SB PowerTech WC GenericDB2 Field Procedures (FieldProcs) were introduced in IBM i 7.1 and have greatly simplified encryption, often without requiring any application changes. Now you can quickly encrypt sensitive data on the IBM i including PII, PCI, PHI data in your physical files and tables.
    Watch this webinar to learn how you can quickly implement encryption on the IBM i. During the webinar, security expert Robin Tatam will show you how to:

    • Use Field Procedures to automate encryption and decryption
    • Restrict and mask field level access by user or group
    • Meet compliance requirements with effective key management and audit trails

     

  • Lessons Learned from IBM i Cyber Attacks

    SB PowerTech WC GenericDespite the many options IBM has provided to protect your systems and data, many organizations still struggle to apply appropriate security controls.
    In this webinar, you'll get insight into how the criminals accessed these systems, the fallout from these attacks, and how the incidents could have been avoided by following security best practices.

    • Learn which security gaps cyber criminals love most
    • Find out how other IBM i organizations have fallen victim
    • Get the details on policies and processes you can implement to protect your organization, even when staff works from home

    You will learn the steps you can take to avoid the mistakes made in these examples, as well as other inadequate and misconfigured settings that put businesses at risk.

     

     

  • The Power of Coding in a Low-Code Solution

    SB PowerTech WC GenericWhen it comes to creating your business applications, there are hundreds of coding platforms and programming languages to choose from. These options range from very complex traditional programming languages to Low-Code platforms where sometimes no traditional coding experience is needed.
    Download our whitepaper, The Power of Writing Code in a Low-Code Solution, and:

    • Discover the benefits of Low-code's quick application creation
    • Understand the differences in model-based and language-based Low-Code platforms
    • Explore the strengths of LANSA's Low-Code Solution to Low-Code’s biggest drawbacks

     

     

  • Node Webinar Series Pt. 1: The World of Node.js on IBM i

    SB Profound WC GenericHave you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application.
    Part 1 will teach you what Node.js is, why it's a great option for IBM i shops, and how to take advantage of the ecosystem surrounding Node.
    In addition to background information, our Director of Product Development Scott Klement will demonstrate applications that take advantage of the Node Package Manager (npm).
    Watch Now.

  • The Biggest Mistakes in IBM i Security

    SB Profound WC Generic The Biggest Mistakes in IBM i Security
    Here’s the harsh reality: cybersecurity pros have to get their jobs right every single day, while an attacker only has to succeed once to do incredible damage.
    Whether that’s thousands of exposed records, millions of dollars in fines and legal fees, or diminished share value, it’s easy to judge organizations that fall victim. IBM i enjoys an enviable reputation for security, but no system is impervious to mistakes.
    Join this webinar to learn about the biggest errors made when securing a Power Systems server.
    This knowledge is critical for ensuring integrity of your application data and preventing you from becoming the next Equifax. It’s also essential for complying with all formal regulations, including SOX, PCI, GDPR, and HIPAA
    Watch Now.

  • Comply in 5! Well, actually UNDER 5 minutes!!

    SB CYBRA PPL 5382

    TRY the one package that solves all your document design and printing challenges on all your platforms.

    Produce bar code labels, electronic forms, ad hoc reports, and RFID tags – without programming! MarkMagic is the only document design and print solution that combines report writing, WYSIWYG label and forms design, and conditional printing in one integrated product.

    Request your trial now!

  • Backup and Recovery on IBM i: Your Strategy for the Unexpected

    FortraRobot automates the routine tasks of iSeries backup and recovery, saving you time and money and making the process safer and more reliable. Automate your backups with the Robot Backup and Recovery Solution. Key features include:
    - Simplified backup procedures
    - Easy data encryption
    - Save media management
    - Guided restoration
    - Seamless product integration
    Make sure your data survives when catastrophe hits. Try the Robot Backup and Recovery Solution FREE for 30 days.

  • Manage IBM i Messages by Exception with Robot

    SB HelpSystems SC 5413Managing messages on your IBM i can be more than a full-time job if you have to do it manually. How can you be sure you won’t miss important system events?
    Automate your message center with the Robot Message Management Solution. Key features include:
    - Automated message management
    - Tailored notifications and automatic escalation
    - System-wide control of your IBM i partitions
    - Two-way system notifications from your mobile device
    - Seamless product integration
    Try the Robot Message Management Solution FREE for 30 days.

  • Easiest Way to Save Money? Stop Printing IBM i Reports

    FortraRobot automates report bursting, distribution, bundling, and archiving, and offers secure, selective online report viewing.
    Manage your reports with the Robot Report Management Solution. Key features include:

    - Automated report distribution
    - View online without delay
    - Browser interface to make notes
    - Custom retention capabilities
    - Seamless product integration
    Rerun another report? Never again. Try the Robot Report Management Solution FREE for 30 days.

  • Hassle-Free IBM i Operations around the Clock

    SB HelpSystems SC 5413For over 30 years, Robot has been a leader in systems management for IBM i.
    Manage your job schedule with the Robot Job Scheduling Solution. Key features include:
    - Automated batch, interactive, and cross-platform scheduling
    - Event-driven dependency processing
    - Centralized monitoring and reporting
    - Audit log and ready-to-use reports
    - Seamless product integration
    Scale your software, not your staff. Try the Robot Job Scheduling Solution FREE for 30 days.