Home > Articles > Web Services > XML

  • Print
  • + Share This
Like this article? We recommend

Getting XML Data into the SQL Server Database

You can pipe XML data into an SQL database by using the OPENXML function. This function supports three parameters:

  • The first parameter is a variable we define, used to load the XML document and pass it to a stored procedure called sp_xml_preparedocument. This stored procedure parses the XML document into an internal version stored in memory that SQL Server will understand.
  • The second parameter tells the function which element path to pull (known as rowpattern). Using this parameter, we can tell the function which nodes to pull by looping through the XML document. We may only want to pull data from certain child elements, for example, or just get the data from the parent elements.
  • The third and final parameter is a value (1–3) that determines the format of the results:
    • The 1 value only pulls data into an SQL table-column format from the specific attributes of elements specified in the rowpattern parameter. An attribute is the value tied to the element; for instance, as the author's ID or first and last names are to the Author element in Listings 1–4. An easy way to think of attributes in a relational sense is that they're column values, and the element of which they're attributes is the table. (This will make more sense soon.)
    • The 2 value only pulls data from inside elements. These are usually elements that don't contain attributes, but rather have their data directly between the beginning and ending element tags. In Listings 1–4, instead of having the Title attribute for the Titles element, we could just have the title data inside the Titles element, with no Title attribute at all.
    • The 3 value pulls both attribute and data from inside elements.

      Using the XML results from Listing 4 in the Query Analyzer, Listings 5–6 show how to use the OPENXML function to convert this XML data back to relational data for SQL Server.

Listing 5 Query for Converting the Author ID

DECLARE @idoc int
DECLARE @xdoc nvarchar(4000)

Set @xmldoc = '<Root>
<Authors au_id="409-56-7008" au_lname="Bennet" au_fname="Abraham">
<Titles title="The Busy Executive&apos;s Database Guide"/></Authors>
<Authors au_id="648-92-1872" au_lname="Blotchet-Halls" au_fname="Reginald">
<Titles title="Fifty Years in Buckingham Palace Kitchens"/></Authors>
<Authors au_id="238-95-7766" au_lname="Carson" au_fname="Cheryl">
<Titles title="But Is It User Friendly"/></Authors>
<Authors au_id="722-51-5454" au_lname="DeFrance" au_fname="Michel">
<Titles title="The Gourmet Microwave"/></Authors>
<Authors au_id="712-45-1867" au_lname="del Castillo" au_fname="Innes">
<Titles title="Silicon Valley Gastronomic Treats"/></Authors>
<Authors au_id="427-17-2319" au_lname="Dull" au_fname="Ann">
<Titles title="Secrets of Silicon Valley"/></Authors>
<Authors au_id="267-41-2394" au_lname="Ellis" au_fname="Michael">
<Titles title="Cooking with Computers: Surreptitious Balance Sheets"/>
<Titles title="Sushi for Anyone"/></Authors>
<Authors au_id="213-46-8915" au_lname="Green" au_fname="Marjorie">
<Titles title="The Busy Executive&apos;s Database Guide"/>
<Titles title="You Can Combat Computer Stress"/></Authors>
</Root>'

EXEC sp_xml_preparedocument @idoc OUTPUT, @xdoc

Select au_id From OPENXML (@idoc,'/Root/Authors',1) WITH Authors

Listing 6 Relational (Table) Data Results

au_id
-----------
409-56-7008
648-92-1872
238-95-7766
722-51-5454
712-45-1867
427-17-2319
267-41-2394
213-46-8915

In this example, the principle is simple. With my SELECT query, I use the OPENXML function to loop through the XML text stored in the idoc variable, using the rowpattern path as /Root/Authors to loop through just the Author elements. I select the author ID (au_id) attribute from the Authors element specified after the WITH clause. You can probably see where this is going and how we can expand it. In short, I turned the author ID back into a column. We could use the 3 value for the third parameter of the OPENXML function and get identical results. The 2 value returns an error because we're using only attributes for our data.

To pull all three attributes of the Authors element (author ID and first and last names) and make them columns again, we only need to specify these attributes in the SELECT clause, as shown in Listings 7–8.

Listing 7 Converting Relational Data Columns from XML Data

DECLARE @idoc int
DECLARE @xdoc nvarchar(4000)

Set @xmldoc = 'XML data string'

EXEC sp_xml_preparedocument @idoc OUTPUT, @xdoc

Select au_id,au_lname,au_fname From OPENXML (@idoc,'/Root/Authors',1) With Authors

Listing 8 Relational (Table) Data Results from Listing 7

au_id       au_lname                                 au_fname
----------- ---------------------------------------- --------------------
409-56-7008 Bennet                                   Abraham
648-92-1872 Blotchet-Halls                           Reginald
238-95-7766 Carson                                   Cheryl
722-51-5454 DeFrance                                 Michel
712-45-1867 del Castillo                             Innes
427-17-2319 Dull                                     Ann
267-41-2394 Ellis                                    Michael
213-46-8915 Green                                    Marjorie

Getting the titles is just as easy. Add the Titles element to the rowpattern parameter, and change the Authors element to the Titles element at the end of the WITH clause of the SELECT query, as shown in Listings 9–10.

Listing 9 Converting the Title Back to Relational Column Data

DECLARE @idoc int
DECLARE @xdoc nvarchar(4000)

Set @xmldoc = 'XML data string'

EXEC sp_xml_preparedocument @idoc OUTPUT, @xdoc

Select title From OPENXML (@idoc,'/Root/Authors/Titles',1) With Titles

Listing 10 Relational (Table) Data Results from Listing 9

title
--------------------------------------------------------------------------------
The Busy Executive's Database Guide
Fifty Years in Buckingham Palace Kitchens
But Is It User Friendly
The Gourmet Microwave
Silicon Valley Gastronomic Treats
Secrets of Silicon Valley
Cooking with Computers: Surreptitious Balance Sheets
Sushi for Anyone
The Busy Executive's Database Guide
You Can Combat Computer Stress

You should now have a pretty good idea of how this technique works. You can do all kinds of things with OPENXML that are beyond the scope of this article—for example, mapping columns explicitly to new variables you define; inserting, updating, and deleting records right into tables from the same SELECT query, and more. OPENXML makes it easy to parse, convert, and transfer data from an XML document right into SQL Server (and all of this is possible as well with ADO, of course).

  • + Share This
  • 🔖 Save To Your Account