Home > Articles > Web Services > XML

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).

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020