Home > Articles > Data > SQL Server

This chapter is from the book

Books Online documents how to use OPENXML pretty well, so I'll try not to repeat that information here.

Listing 18.17 shows a basic example of how to use OPENXML.



Listing 18.17

DECLARE @hDoc int
EXEC sp_xml_preparedocument @hDoc output,
'<songs>
  <song><name>Somebody to Love</name></song>
  <song><name>These Are the Days of Our Lives</name></song>
  <song><name>Bicycle Race</name></song>
  <song><name>Who Wants to Live Forever</name></song>
  <song><name>I Want to Break Free</name></song>
  <song><name>Friends Will Be Friends</name></song>
</songs>'
SELECT * FROM OPENXML(@hdoc, '/songs/song', 2) WITH
    (name varchar(80))
EXEC sp_xml_removedocument @hDoc

(Results)

name
------------------------------------------------------------------
Somebody to Love
These Are the Days of Our Lives
Bicycle Race
Who Wants to Live Forever
I Want to Break Free
Friends Will Be Friends

To use OPENXML, follow these basic steps.

  1. Call sp_xml_preparedocument to load the XML document into memory. MSXML's DOM parser is called to translate the document into a tree of nodes that you can then access with an XPath query. A pointer to this tree is returned by the procedure as an integer.

  2. Issue a SELECT statement from OPENXML, passing in the handle you received in step 1.

  3. Include XPath syntax in the call to OPENXML in order to specify exactly which nodes you want to access.

  4. Optionally include a WITH clause that maps the XML document into a specific table schema. This can be a full table schema as well as a reference to a table itself.

OPENXML is extremely flexible, so several of these steps have variations and alternatives, but this is the basic process you follow to shred and use an XML document with OPENXML.

Listing 18.18 presents a variation of the earlier query that employs a table to define the schema used to map the document.

Listing 18.18

USE tempdb
GO
create table songs (name varchar(80))
go
DECLARE @hDoc int
EXEC sp_xml_preparedocument @hDoc output,
'<songs>
  <song><name>Somebody to Love</name></song>
  <song><name>These Are the Days of Our Lives</name></song>
  <song><name>Bicycle Race</name></song>
  <song><name>Who Wants to Live Forever</name></song>
  <song><name>I Want to Break Free</name></song>
  <song><name>Friends Will Be Friends</name></song>
</songs>'
SELECT * FROM OPENXML(@hdoc, '/songs/song', 2) WITH songs
EXEC sp_xml_removedocument @hDoc
GO
DROP TABLE songs

(Results)

name
------------------------------------------------------------------
Somebody to Love
These Are the Days of Our Lives
Bicycle Race
Who Wants to Live Forever
I Want to Break Free
Friends Will Be Friends

You can also use the WITH clause to set up detailed mappings between the XML document and the tables in your database, as shown in Listing 18.19.

Listing 18.19

DECLARE @hDoc int
EXEC sp_xml_preparedocument @hDoc output,
'<songs>
  <artist name="Johnny Hartman">
  <song> <name>It Was Almost Like a Song</name></song>
  <song> <name>I See Your Face Before Me</name></song>
  <song> <name>For All We Know</name></song>
  <song> <name>Easy Living</name></song>
  </artist>
  <artist name="Harry Connick, Jr.">
  <song> <name>Sonny Cried</name></song>
  <song> <name>A Nightingale Sang in Berkeley Square</name></song>
  <song> <name>Heavenly</name></song>
  <song> <name>You Didn''t Know Me When</name></song>
  </artist>
</songs>'
SELECT * FROM OPENXML(@hdoc, '/songs/artist/song', 2)
WITH (artist varchar(30) '../@name',
      song varchar(50) 'name')
EXEC sp_xml_removedocument @hDoc

(Results)

artist                       song
--------------------------- --------------------------------------
Johnny Hartman               It Was Almost Like a Song
Johnny Hartman               I See Your Face Before Me
Johnny Hartman               For All We Know
Johnny Hartman               Easy Living
Harry Connick, Jr.           Sonny Cried
Harry Connick, Jr.           A Nightingale Sang in Berkeley Square
Harry Connick, Jr.           Heavenly
Harry Connick, Jr.           You Didn't Know Me When

Note that attribute references are prefixed with the @ symbol. In Listing 18.19, we supply an XPath query that navigates the tree down to the song element, then reference an attribute called name in song's parent element, artist. For the second column, we retrieve a child element of song that's also called name.

Listing 18.20 offers another example.

Listing 18.20

DECLARE @hDoc int
EXEC sp_xml_preparedocument @hDoc output,
'<songs>
  <artist> <name>Johnny Hartman</name>
  <song> <name>It Was Almost Like a Song</name></song>
  <song> <name>I See Your Face Before Me</name></song>
  <song> <name>For All We Know</name></song>
  <song> <name>Easy Living</name></song>
  </artist>
  <artist> <name>Harry Connick, Jr.</name>
  <song> <name>Sonny Cried</name></song>
  <song> <name>A Nightingale Sang in Berkeley Square</name></song>
  <song> <name>Heavenly</name></song>
  <song> <name>You Didn''t Know Me When</name></song>
  </artist>
</songs>'
SELECT * FROM OPENXML(@hdoc, '/songs/artist/name', 2)
WITH (artist varchar(30) '.',
      song varchar(50) '../song/name')
EXEC sp_xml_removedocument @hDoc

(Results)

artist                       song
--------------------------- --------------------------------------
Johnny Hartman               It Was Almost Like a Song
Harry Connick, Jr.           Sonny Cried

Notice that we get only two rows. Why is that? It's due to the fact that our XPath pattern navigated to the artist/name node, of which there are only two. In addition to getting each artist's name element, we also grabbed the name of its first song element. In the previous query, the XPath pattern navigated us to the song element, of which there were eight, then referenced each song's parent node (its artist) via the XPath “..” designator.

Note the use in the above query of the XPath “.” specifier. This merely references the current element. We need it here because we are changing the name of the current element from name to artist. Keep this technique in mind when you want to rename an element you're returning via OPENXML.

The flags Parameter

OPENXML's flags parameter allows you to specify whether OPENXML should process the document in an attribute-centric fashion, an element-centric fashion, or some combination of the two. Thus far, we've been specifying 2 for the flags parameter, which specifies element-centric mapping. Listing 18.21 shows an example of attribute-centric mapping.

Listing 18.21

DECLARE @hDoc int
EXEC sp_xml_preparedocument @hDoc output,
'<songs>
  <artist name="Johnny Hartman">
  <song name="It Was Almost Like a Song"/>
  <song name="I See Your Face Before Me"/>
  <song name="For All We Know"/>
  <song name="Easy Living"/>
  </artist>
  <artist name="Harry Connick, Jr.">
  <song name="Sonny Cried"/>
  <song name="A Nightingale Sang in Berkeley Square"/>
  <song name="Heavenly"/>
  <song name="You Didn''t Know Me When"/>
  </artist>
</songs>'
SELECT * FROM OPENXML(@hdoc, '/songs/artist/song', 1)
WITH (artist varchar(30) '../@name',
      song varchar(50) '@name')
EXEC sp_xml_removedocument @hDoc

(Results)

artist                       song
--------------------------- --------------------------------------
Johnny Hartman               It Was Almost Like a Song
Johnny Hartman               I See Your Face Before Me
Johnny Hartman               For All We Know
Johnny Hartman               Easy Living
Harry Connick, Jr.           Sonny Cried
Harry Connick, Jr.           A Nightingale Sang in Berkeley Square
Harry Connick, Jr.           Heavenly
Harry Connick, Jr.           You Didn't Know Me When

Edge Table Format

You can completely omit OPENXML's WITH clause in order to retrieve a portion of an XML document in “edge table format”—essentially a two-dimensional representation of the XML tree. Listing 18.22 provides an example.

Listing 18.22

DECLARE @hDoc int
EXEC sp_xml_preparedocument @hDoc output,
'<songs>
  <artist name="Johnny Hartman">
  <song> <name>It Was Almost Like a Song</name></song>
  <song> <name>I See Your Face Before Me</name></song>
  <song> <name>For All We Know</name></song>
  <song> <name>Easy Living</name></song>
  </artist>
  <artist name="Harry Connick, Jr.">
  <song> <name>Sonny Cried</name></song>
  <song> <name>A Nightingale Sang in Berkeley Square</name></song>
  <song> <name>Heavenly</name></song>
  <song> <name>You Didn''t Know Me When</name></song>
  </artist>
</songs>'
SELECT * FROM OPENXML(@hdoc, '/songs/artist/song', 2)
EXEC sp_xml_removedocument @hDoc

(Results abridged)

id                   parentid             nodetype    localname
-------------------- -------------------- ----------- -----------
4                    2                    1           song
5                    4                    1           name
22                   5                    3           #text
6                    2                    1           song
7                    6                    1           name
23                   7                    3           #text
8                    2                    1           song
9                    8                    1           name
24                   9                    3           #text
10                   2                    1           song
11                   10                   1           name
25                   11                   3           #text
14                   12                   1           song
15                   14                   1           name
26                   15                   3           #text
16                   12                   1           song
17                   16                   1           name
27                   17                   3           #text
18                   12                   1           song
19                   18                   1           name
28                   19                   3           #text
20                   12                   1           song
21                   20                   1           name
29                   21                   3           #text

Inserting Data with OPENXML

Given that it's a rowset function, it's natural that you'd want to insert the results of a SELECT against OPENXML into another table. There are a couple of ways to approach this. First, you could execute a separate pass against the XML document for each piece of it you wanted to extract. You would execute an INSERT…SELECT FROM OPENXML for each table you wanted to insert rows into, grabbing a different section of the XML document with each pass, as demonstrated in Listing 18.23.

Listing 18.23

USE tempdb
GO
CREATE TABLE Artists
(ArtistId varchar(5),
  Name varchar(30))
GO
CREATE TABLE Songs
(ArtistId varchar(5),
  SongId int,
  Name varchar(50))
GO

DECLARE @hDoc int
EXEC sp_xml_preparedocument @hDoc output,
'<songs>
  <artist id="JHART" name="Johnny Hartman">
  <song id="1" name="It Was Almost Like a Song"/>
  <song id="2" name="I See Your Face Before Me"/>
  <song id="3" name="For All We Know"/>
  <song id="4" name="Easy Living"/>
  </artist>
  <artist id="HCONN" name="Harry Connick, Jr.">
  <song id="1" name="Sonny Cried"/>
  <song id="2" name="A Nightingale Sang in Berkeley Square"/>
  <song id="3" name="Heavenly"/>
  <song id="4" name="You Didn''t Know Me When"/>
  </artist>
</songs>'
INSERT Artists (ArtistId, Name)
SELECT id,name
FROM OPENXML(@hdoc, '/songs/artist', 1)
WITH (id varchar(5) '@id',
      name varchar(30) '@name')

INSERT Songs (ArtistId, SongId, Name)
SELECT artistid, id,name
FROM OPENXML(@hdoc, '/songs/artist/song', 1)
WITH (artistid varchar(5) '../@id',
      id int '@id',
      name varchar(50) '@name')
EXEC sp_xml_removedocument @hDoc
GO
SELECT * FROM Artists
SELECT * FROM Songs
GO
DROP TABLE Artists, Songs

(Results)

ArtistId Name
-------- ------------------------------
JHART    Johnny Hartman
HCONN    Harry Connick, Jr.

ArtistId SongId      Name
-------- ----------- ---------------------------------------------
JHART    1           It Was Almost Like a Song
JHART    2           I See Your Face Before Me
JHART    3           For All We Know
JHART    4           Easy Living
HCONN    1           Sonny Cried
HCONN    2           A Nightingale Sang in Berkeley Square
HCONN    3           Heavenly
HCONN    4           You Didn't Know Me When

As you can see, we make a separate call to OPENXML for each table. The tables are normalized; the XML document is not, so we shred it into multiple tables. Listing 18.24 shows another way to accomplish the same thing that doesn't require multiple calls to OPENXML.

Listing 18.24

USE tempdb
GO
CREATE TABLE Artists
(ArtistId varchar(5),
  Name varchar(30))
GO
CREATE TABLE Songs
(ArtistId varchar(5),
  SongId int,
  Name varchar(50))
GO
CREATE VIEW ArtistSongs AS
SELECT a.ArtistId,
       a.Name AS ArtistName,
       s.SongId,
       s.Name as SongName
FROM Artists a JOIN Songs s
ON (a.ArtistId=s.ArtistId)
GO
CREATE TRIGGER ArtistSongsInsert ON ArtistSongs INSTEAD OF
    INSERT AS
INSERT Artists
SELECT DISTINCT ArtistId, ArtistName FROM inserted
INSERT Songs
SELECT ArtistId, SongId, SongName FROM inserted
GO

DECLARE @hDoc int
EXEC sp_xml_preparedocument @hDoc output,
'<songs>
  <artist id="JHART" name="Johnny Hartman">
  <song id="1" name="It Was Almost Like a Song"/>
  <song id="2" name="I See Your Face Before Me"/>
  <song id="3" name="For All We Know"/>
  <song id="4" name="Easy Living"/>
  </artist>
  <artist id="HCONN" name="Harry Connick, Jr.">
  <song id="1" name="Sonny Cried"/>
  <song id="2" name="A Nightingale Sang in Berkeley Square"/>
  <song id="3" name="Heavenly"/>
  <song id="4" name="You Didn''t Know Me When"/>
  </artist>
</songs>'
INSERT ArtistSongs (ArtistId, ArtistName, SongId, SongName)
SELECT artistid, artistname, songid, songname
FROM OPENXML(@hdoc, '/songs/artist/song', 1)
WITH (artistid varchar(5) '../@id',
      artistname varchar(30) '../@name',
      songid int '@id',
      songname varchar(50) '@name')

EXEC sp_xml_removedocument @hDoc
GO
SELECT * FROM Artists
SELECT * FROM Songs
GO
DROP VIEW ArtistSongs
GO
DROP TABLE Artists, Songs

(Results)

ArtistId Name
-------- ------------------------------
HCONN    Harry Connick, Jr.
JHART    Johnny Hartman

ArtistId SongId      Name
-------- ----------- ---------------------------------------------
JHART    1           It Was Almost Like a Song
JHART    2           I See Your Face Before Me
JHART    3           For All We Know
JHART    4           Easy Living
HCONN    1           Sonny Cried
HCONN    2           A Nightingale Sang in Berkeley Square
HCONN    3           Heavenly
HCONN    4           You Didn't Know Me When

This technique uses a view and an INSTEAD OF trigger to alleviate the need for two passes with OPENXML. We use a view to simulate the denormalized layout of the XML document, then set up an INSTEAD OF trigger to allow us to insert the data in the XML document “into” this view. The trigger performs the actual work of shredding, only it does so much more efficiently than calling OPENXML twice. It makes two passes over the logical inserted table and splits the columns contained therein (which mirror those of the view) into two separate tables.

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