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.
-
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.
-
Issue a SELECT statement from OPENXML, passing in the handle you received in step 1.
-
Include XPath syntax in the call to OPENXML in order to specify exactly which nodes you want to access.
-
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.