Using XML Data With Transact-SQL
In the preceding section, you learned how to select data from SQL Server in XML format. In this section you learn how to use XML data inside SQL Server as part of any script, stored procedure, or trigger.
SQL Server 2000 implements the new OPENXML function to read XML documents as result sets, so they can be used in the FROM clause of any Data Manipulation Language (DML) statement.
The process of reading XML data involves the following steps:
The process receives the XML document, usually as a parameter in a stored procedure or a string stored in a table.
The process calls the sp_xml_preparedocument extended stored procedure to create a memory representation of the XML document. SQL Server creates a tree structure in memory that represents the XML document and returns an integer, which acts as a handle to the tree structure.
Use the OPENXML function to read the XML data in result set format on any Transact-SQL DML statement, as if it were a result set.
Use the sp_xml_removedocument extended stored procedure to destroy the memory representation of the XML document when it is no longer required.
Note
Both procedures, sp_xml_preparedocument and sp_xml_removedocument, are extended procedures that call external libraries. That their name starts with sp_ means that these procedures are global and can be called from any database, without specifying master as the database name.
Listing 16.19 contains an example of using the XML document from Listing 16.1.
Listing 16.19Using the OPENXML Function to Read an XML Document from a Transact-SQL Script
DECLARE @xml varchar(8000) -- This is the XML Document SET @xml = '<Products>' SET @xml = @xml + '<Product ProductID="1" ' SET @xml = @xml + 'ProductName="Chai" UnitPrice="18.0000"/>' SET @xml = @xml + '<Product ProductID="2" ' SET @xml = @xml + 'ProductName="Chang" UnitPrice="19.0000"/>' SET @xml = @xml + '<Product ProductID="3" ' SET @xml = @xml + 'ProductName="Aniseed Syrup" UnitPrice="10.0000"/>' SET @xml = @xml + '</Products>' -- Create a tree structure with the XML document -- and retrieve its handle DECLARE @iDoc int EXEC sp_xml_preparedocument @iDoc OUTPUT, @xml PRINT CHAR(10) + 'Tree created, handle = ' + CONVERT(varchar(10), @iDoc) + CHAR(10) SELECT * FROM OPENXML(@iDoc, 'Products', 1) EXEC sp_xml_removedocument @idoc
Tree created, handle = 13 id parentid nodetype localname prefix namespaceuri datatype prev text ----- -------- -------- ----------- ------ ------------ -------- ---- --------- 0.00 NULL 1.00 Products NULL NULL NULL NULL NULL 2.00 0.00 1.00 Product NULL NULL NULL NULL NULL 3.00 2.00 2.00 ProductID NULL NULL NULL NULL NULL 14.00 3.00 3.00 #text NULL NULL NULL NULL 1 4.00 2.00 2.00 ProductName NULL NULL NULL NULL NULL 15.00 4.00 3.00 #text NULL NULL NULL NULL Chai 5.00 2.00 2.00 UnitPrice NULL NULL NULL NULL NULL 16.00 5.00 3.00 #text NULL NULL NULL NULL 18.0000 6.00 0.00 1.00 Product NULL NULL NULL 2.00 NULL 7.00 6.00 2.00 ProductID NULL NULL NULL NULL NULL 17.00 7.00 3.00 #text NULL NULL NULL NULL 2 8.00 6.00 2.00 ProductName NULL NULL NULL NULL NULL 18.00 8.00 3.00 #text NULL NULL NULL NULL Chang 9.00 6.00 2.00 UnitPrice NULL NULL NULL NULL NULL 19.00 9.00 3.00 #text NULL NULL NULL NULL 19.0000 10.00 0.00 1.00 Product NULL NULL NULL 6.00 NULL 11.00 10.00 2.00 ProductID NULL NULL NULL NULL NULL 20.00 11.00 3.00 #text NULL NULL NULL NULL 3 12.00 10.00 2.00 ProductName NULL NULL NULL NULL NULL 21.00 12.00 3.00 #text NULL NULL NULL NULL Aniseed Syrup 13.00 10.00 2.00 UnitPrice NULL NULL NULL NULL NULL 22.00 13.00 3.00 #text NULL NULL NULL NULL 10.0000 (22 row(s) affected)
The output from Listing 16.19 is not exactly what we wanted. It contains too many fields and 22 rows. However, our XML document has only 3 products with 3 fields each. The result set produced is called an edge table, which contains metadata to build custom XML document management systems.
To retrieve the rows and columns you want, you must provide the table structure with the WITH clause, as in Listing 16.20. The only difference from Listing 16.19 is the SELECT statement.
Listing 16.20Use the WITH Clause to Specify the Columns to Retrieve
DECLARE @xml varchar(8000) -- This is the XML Document SET @xml = '<Products>' SET @xml = @xml + '<Product ProductID="1" ' SET @xml = @xml + 'ProductName="Chai" UnitPrice="18.0000"/>' SET @xml = @xml + '<Product ProductID="2" ' SET @xml = @xml + 'ProductName="Chang" UnitPrice="19.0000"/>' SET @xml = @xml + '<Product ProductID="3" ' SET @xml = @xml + 'ProductName="Aniseed Syrup" UnitPrice="10.0000"/>' SET @xml = @xml + '</Products>' -- Create a tree structure with the XML document -- and retrieve its handle DECLARE @iDoc int EXEC sp_xml_preparedocument @iDoc OUTPUT, @xml PRINT CHAR(10) + 'Tree created, handle = ' + CONVERT(varchar(10), @iDoc) + CHAR(10) SELECT * FROM OPENXML(@iDoc, 'Products/Product', 1) WITH (ProductID int, ProductName nvarchar(40), UnitPrice money) EXEC sp_xml_removedocument @idoc
Tree created, handle = 21 ProductID ProductName UnitPrice ----------- ------------------------------ --------------------- 1.00 Chai $18.00 2.00 Chang $19.00 3.00 Aniseed Syrup $10.00 (3 row(s) affected)
The result from Listing 16.20 is more readable than Listing 16.19. It is as any other SQL result set.
CAUTION
If you do not execute the sp_xml_removedocument procedure, the tree structure will remain in memory until the server reboots. This can produce some memory problems with big XML documents.
The OPENXML Function
The example from Listing 16.20 is very simple: It contains only three elements from a single entity and only three attributes for every element. You can use the OPENXML function to retrieve result sets from more complex XML documents.
Consider the XML document from 16.4, which has hierarchical information from Customers, Orders, and Products. You can read this document from Transact-SQL in different ways using the OPENXML function. Listing 16.21 shows some examples of how to use the OPENXML function to select which information to read from an XML document. In this case you can execute queries to extract orders, customers, products, or order details information, all from the same XML document.
Listing 16.21Use the OPENXML Function with the WITH Clause to Read an XML Hierarchical Document
-- This is the XML Document DECLARE @XML varchar(8000) SET @XML = ' <Customers> <Customer CompanyName="Victuailles en stock"> <Order Date="1996-07-08"> <Product Name="Gustafaposs Knackebrod" Price="16.8000" Quantity="6"/> <Product Name="Ravioli Angelo" Price="15.6000" Quantity="15"/> <Product Name="Louisiana Fiery Hot Pepper Sauce" Price="16.8000" Quantity="20"/> </Order> <Order Date="1996-10-21"> <Product Name="Filo Mix" Price="5.6000" Quantity="8"/> <Product Name="Scottish Longbreads" Price="10.0000" Quantity="10"/> </Order> <Order Date="1997-02-19"> <Product Name="Ikura" Price="24.8000" Quantity="20"/> <Product Name="Tourtiere" Price="5.9000" Quantity="6"/> </Order> <Order Date="1997-02-27"> <Product Name="Uncle Bobaposs Organic Dried Pears" Price="24.0000" Quantity="16"/> <Product Name="Spegesild" Price="9.6000" Quantity="20"/> <Product Name="Mozzarella di Giovanni" Price="27.8000" Quantity="40"/> </Order> <Order Date="1997-03-18"> <Product Name="Ikura" Price="24.8000" Quantity="20"/> </Order> <Order Date="1997-05-23"> <Product Name="Uncle Bobaposs Organic Dried Pears" Price="30.0000" Quantity="10"/> <Product Name="Steeleye Stout" Price="18.0000" Quantity="30"/> <Product Name="Tarte au sucre" Price="49.3000" Quantity="40"/> </Order> <Order Date="1997-12-31"> <Product Name="Chang" Price="19.0000" Quantity="20"/> <Product Name="Louisiana Fiery Hot Pepper Sauce" Price="21.0500" Quantity="2"/> <Product Name="Longlife Tofu" Price="10.0000" Quantity="15"/> </Order> </Customer> <Customer CompanyName="Vins et alcohols Chevalier"> <Order Date="1996-07-04"> <Product Name="Queso Cabrales" Price="14.0000" Quantity="12"/> <Product Name="Singaporean Hokkien Fried Mee" Price="9.8000" Quantity="10"/> <Product Name="Mozzarella di Giovanni" Price="34.8000" Quantity="5"/> </Order> <Order Date="1996-08-06"> <Product Name="Flotemysost" Price="17.2000" Quantity="20"/> <Product Name="Mozzarella di Giovanni" Price="27.8000" Quantity="7"/> </Order> <Order Date="1996-09-02"> <Product Name="Gnocchi di nonna Alice" Price="30.4000" Quantity="4"/> </Order> <Order Date="1997-11-11"> <Product Name="Konbu" Price="6.0000" Quantity="4"/> <Product Name="Jack's New England Clam Chowder" Price="9.6500" Quantity="12"/> </Order> <Order Date="1997-11-12"> <Product Name="Inlagd Sill" Price="19.0000" Quantity="6"/> <Product Name="Filo Mix" Price="7.0000" Quantity="18"/> </Order> </Customer> </Customers> ' -- Create a tree structure with the XML document -- and retrieve its handle DECLARE @iDoc int EXEC sp_xml_preparedocument @iDoc OUTPUT, @xml PRINT CHAR(10) + 'Tree created, handle = ' + CONVERT(varchar(10), @iDoc) + CHAR(10) PRINT CHAR(10) + 'Query 1' + CHAR(10) + 'Product Information' + CHAR(10) SELECT * FROM OPENXML(@iDoc, 'Customers/Customer/Order/Product', 1) WITH (Name nvarchar(40), Price money, Quantity int) PRINT CHAR(10) + 'Query 2' + CHAR(10) + 'Order Information' + CHAR(10) SELECT * FROM OPENXML(@iDoc, 'Customers/Customer/Order', 1) WITH (Date smalldatetime) PRINT CHAR(10) + 'Query 3' + CHAR(10) + 'Customer Information' + CHAR(10) SELECT * FROM OPENXML(@iDoc, 'Customers/Customer', 1) WITH (CompanyName nvarchar(40)) PRINT CHAR(10) + 'Query 4' + CHAR(10) + 'Combining Attributes from different levels' + CHAR(10) SELECT CompanyName, CONVERT(varchar(10), [Date], 102) As Date, Name, Price, Quantity FROM OPENXML(@iDoc, 'Customers/Customer/Order/Product', 1) WITH (CompanyName nvarchar(40) '../../@CompanyName', Date smalldatetime '../@Date', Name nvarchar(40), Price money, Quantity int) PRINT CHAR(10) + 'Query 5' + CHAR(10) + 'Executing a XPatch query' + CHAR(10) + 'to extract product ordered with wuantity > 20' + CHAR(10) SELECT CompanyName, CONVERT(varchar(10), [Date], 102) As Date, Name, Price, Quantity FROM OPENXML(@iDoc, 'Customers/Customer/Order/Product[@Quantity>20]', 1) WITH (CompanyName nvarchar(40) '../../@CompanyName', Date smalldatetime '../@Date', Name nvarchar(40), Price money, Quantity int) EXEC sp_xml_removedocument @idoc
Tree created, handle = 25 Query 1 Product Information Name Price Quantity ---------------------------------------- --------------------- ----------- Gustafaposs Knackebrod $16.80 6.00 Ravioli Angelo $15.60 15.00 Louisiana Fiery Hot Pepper Sauce $16.80 20.00 Filo Mix $5.60 8.00 Scottish Longbreads $10.00 10.00 Ikura $24.80 20.00 Tourtiere $5.90 6.00 Uncle Bobaposs Organic Dried Pears $24.00 16.00 Spegesild $9.60 20.00 Mozzarella di Giovanni $27.80 40.00 Ikura $24.80 20.00 Uncle Bobaposs Organic Dried Pears $30.00 10.00 Steeleye Stout $18.00 30.00 Tarte au sucre $49.30 40.00 Chang $19.00 20.00 Louisiana Fiery Hot Pepper Sauce $21.05 2.00 Longlife Tofu $10.00 15.00 Queso Cabrales $14.00 12.00 Singaporean Hokkien Fried Mee $9.80 10.00 Mozzarella di Giovanni $34.80 5.00 Flotemysost $17.20 20.00 Mozzarella di Giovanni $27.80 7.00 Gnocchi di nonna Alice $30.40 4.00 Konbu $6.00 4.00 Jack's New England Clam Chowder $9.65 12.00 Inlagd Sill $19.00 6.00 Filo Mix $7.00 18.00 (27 row(s) affected) Query 2 Order Information Date -------------------------------------------------- 7/8/1996 12:00:00 AM 10/21/1996 12:00:00 AM 2/19/1997 12:00:00 AM 2/27/1997 12:00:00 AM 3/18/1997 12:00:00 AM 5/23/1997 12:00:00 AM 12/31/1997 12:00:00 AM 7/4/1996 12:00:00 AM 8/6/1996 12:00:00 AM 9/2/1996 12:00:00 AM 11/11/1997 12:00:00 AM 11/12/1997 12:00:00 AM (12 row(s) affected) Query 3 Customer Information CompanyName ---------------------------------------- Victuailles en stock Vins et alcohols Chevalier (2 row(s) affected) Query 4 Combining Attributes from different levels CompanyName Date Name Price Quantity -------------------- ---------- ---------------------------- ------ -------- Victuailles en stock 1996.07.08 Gustafaposs Knackebrod $16.80 6.00 Victuailles en stock 1996.07.08 Ravioli Angelo $15.60 15.00 Victuailles en stock 1996.07.08 Louisiana Fiery Hot Pepper $16.80 20.00 Victuailles en stock 1996.10.21 Filo Mix $5.60 8.00 Victuailles en stock 1996.10.21 Scottish Longbreads $10.00 10.00 Victuailles en stock 1997.02.19 Ikura $24.80 20.00 Victuailles en stock 1997.02.19 Tourtiere $5.90 6.00 Victuailles en stock 1997.02.27 Uncle Bobaposs Organic Dried $24.00 16.00 Victuailles en stock 1997.02.27 Spegesild $9.60 20.00 Victuailles en stock 1997.02.27 Mozzarella di Giovanni $27.80 40.00 Victuailles en stock 1997.03.18 Ikura $24.80 20.00 Victuailles en stock 1997.05.23 Uncle Bobaposs Organic Dried $30.00 10.00 Victuailles en stock 1997.05.23 Steeleye Stout $18.00 30.00 Victuailles en stock 1997.05.23 Tarte au sucre $49.30 40.00 Victuailles en stock 1997.12.31 Chang $19.00 20.00 Victuailles en stock 1997.12.31 Louisiana Fiery Hot Pepper $21.05 2.00 Victuailles en stock 1997.12.31 Longlife Tofu $10.00 15.00 Vins et alcohols 1996.07.04 Queso Cabrales $14.00 12.00 Vins et alcohols 1996.07.04 Singaporean Hokkien Fried $9.80 10.00 Vins et alcohols 1996.07.04 Mozzarella di Giovanni $34.80 5.00 Vins et alcohols 1996.08.06 Flotemysost $17.20 20.00 Vins et alcohols 1996.08.06 Mozzarella di Giovanni $27.80 7.00 Vins et alcohols 1996.09.02 Gnocchi di nonna Alice $30.40 4.00 Vins et alcohols 1997.11.11 Konbu $6.00 4.00 Vins et alcohols 1997.11.11 Jack's New England Clam $9.65 12.00 Vins et alcohols 1997.11.12 Inlagd Sill $19.00 6.00 Vins et alcohols 1997.11.12 Filo Mix $7.00 18.00 (27 row(s) affected) Query 5 Executing a XPath query to extract product ordered with wuantity > 20 CompanyName Date Name Price Quantity -------------------- ---------- ---------------------------- ------ -------- Victuailles en stock 1997.02.27 Mozzarella di Giovanni $27.80 40.00 Victuailles en stock 1997.05.23 Steeleye Stout $18.00 30.00 Victuailles en stock 1997.05.23 Tarte au sucre $49.30 40.00 (3 row(s) affected)
Take a closer look at the examples from Listing 16.21.
The first example uses the following query:
SELECT * FROM OPENXML(@iDoc, 'Customers/Customer/Order/Product', 1) WITH (Name nvarchar(40), Price money, Quantity int)
With this query, you can retrieve only data at Product level, because 'Customers/Customer/Order/Product' defines the path of the data in the OPENXML function. The WITH clause contains the fields to retrieve using the default mappings.
When you execute this query, you can obtain 27 rows, one for every product contained in the XML document.
The second example retrieves only the order date from the Order level (selected by its path 'Customers/Customer/Order'):
SELECT * FROM OPENXML(@iDoc, 'Customers/Customer/Order', 1) WITH (Date smalldatetime)
The third example retrieves only company names from the Customer level (selected by its path 'Customers/Customer'):
SELECT * FROM OPENXML(@iDoc, 'Customers/Customer', 1) WITH (CompanyName nvarchar(40))
So far, it has been quite simple. You select the path to the data you want to retrieve in the second parameter of the OPENXML function and specify the column definitions in the WITH clause.
The fourth example is a little more complex, because you want to retrieve some information from every level, combining the output from the previous three examples:
SELECT CompanyName, CONVERT(varchar(10), [Date], 102) As Date, Name, Price, Quantity FROM OPENXML(@iDoc, 'Customers/Customer/Order/Product', 1) WITH (CompanyName nvarchar(40) '../../@CompanyName', Date smalldatetime '../@Date', Name nvarchar(40), Price money, Quantity int)
The base level is still Product, that's why the path is 'Customers/Customer/Order/Product'. The WITH clause contains the Date field from the Order level, and the CompanyName field from the Customer level.
To read the Date field, which does not belong to the Product level, you must specify its path '../@Date', which means, "Go up one level and read the Date attribute."
For the CompanyName field, the path is '../../@CompanyName', which means, "Go up two levels and read the CompanyName attribute."
The last example executes an Xpath query to restrict the result set. In this case, you are only interested in orders that contain more than 20 units of any given product. You can specify this condition as the path 'Customers/Customer/Order/Product[@Quantity>20]':
SELECT CompanyName, CONVERT(varchar(10), [Date], 102) As Date, Name, Price, Quantity FROM OPENXML(@iDoc, 'Customers/Customer/Order/Product[@Quantity>20]', 1) WITH (CompanyName nvarchar(40) '../../@CompanyName', Date smalldatetime '../@Date', Name nvarchar(40), Price money, Quantity int)
Microsoft SQL Server 2000 implements a subset of the World Wide Web Consortium (W3C) XPath specification. You can obtain more information about the XPath specification at http://www.w3.org/TR/xpath.
SQL Server Books Online contains full description of the subset implemented in this version of SQL Server. You can search for the topic "Using XPath Queries" in Books Online.
Tip
In the example from Listing 16.21 you create the XML document in a varchar field, which is limited to 8000 bytes.
You cannot create a variable of ntext data type, but you can have a parameter in a stored procedure of ntext data type, expanding the size of the XML documents to process to up to almost 2 Gigabytes.
It is important to define XML-based parameters as ntext instead of text to be able to manage UNICODE XML documents.
You might wonder what the third parameter in the OPENXML function is. This parameter selects the type of values used in the XML document:
0 Defaults to attribute-centric mapping.
1 Use the attribute-centric mapping.
2 Use the element-centric mapping.
8 Can combine attributes-centric or element-centric mapping.
As the examples you use in Listing 16.21 contain only attributes, the value of this third parameter is always 1.
Combining XML Data with SQL Data
As the OPENXML function returns a result set, you can join this result set to other tables or rowset functions, such as OPENROWSET, OPENDATASOURCE, or OPENQUERY.
Listing 16.22 shows an example of joining the result set from OPENXML to the Orders and [Order Details] tables.
Listing 16.22You Can Join the Result Set from OPENXML to Other Tables or Result Sets
DECLARE @xml varchar(8000) -- This is the XML Document SET @xml = '<Products>' SET @xml = @xml + '<Product ProductID="1" ' SET @xml = @xml + 'ProductName="Chai" UnitPrice="18.0000"/>' SET @xml = @xml + '<Product ProductID="2" ' SET @xml = @xml + 'ProductName="Chang" UnitPrice="19.0000"/>' SET @xml = @xml + '<Product ProductID="3" ' SET @xml = @xml + 'ProductName="Aniseed Syrup" UnitPrice="10.0000"/>' SET @xml = @xml + '</Products>' -- Create a tree structure with the XML document -- and retrieve its handle DECLARE @iDoc int EXEC sp_xml_preparedocument @iDoc OUTPUT, @xml PRINT CHAR(10) + 'Tree created, handle = ' + CONVERT(varchar(10), @iDoc) + CHAR(10) -- Joins the result set from OPENXML -- to the Orders table and the [Order Details] table SELECT CONVERT(varchar(10), OrderDate, 102) AS Date, ProductName, P.UnitPrice, OD.Quantity FROM OPENXML(@iDoc, 'Products/Product', 1) WITH (ProductID int, ProductName nvarchar(40), UnitPrice money) AS P JOIN [Order Details] OD ON OD.ProductID = P.ProductID JOIN Orders O ON O.OrderID = OD.OrderID WHERE Quantity > 20 AND Year(OrderDate) = 1996 EXEC sp_xml_removedocument @idoc
Tree created, handle = 11 Date ProductName UnitPrice Quantity ---------- ------------------------------ --------------------- -------- 1996.08.20 Chai $18.00 45.00 1996.10.30 Chang $19.00 24.00 1996.12.25 Chang $19.00 25.00 1996.09.05 Chang $19.00 40.00 1996.10.11 Chang $19.00 25.00 1996.07.17 Chang $19.00 50.00 1996.07.24 Chang $19.00 35.00 1996.08.26 Aniseed Syrup $10.00 30.00 (8 row(s) affected)