Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


XML Workshop : Utilizing Relational Data In XML Files


XML Workshop : Utilizing Relational Data In XML Files

Author
Message
Matthew Pettit
Matthew Pettit
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 164
Comments posted to this topic are about the item XML Workshop : Utilizing Relational Data In XML Files

Matthew
Eirikur Eiriksson
Eirikur Eiriksson
SSCrazy Eights
SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)

Group: General Forum Members
Points: 8868 Visits: 18226
Hi Matthew,
and thank you for this article.
Few comments, firstly the sp_xml_preparedocument and sp_xml_removedocument have some limitations and quite an overhead, I'm very hesitant recommending / implementing them on a production system. XQuery on the XML data type is without those limitations and in terms of importing XML data, only bound by the 2Gb size limit of the XML variable.

Secondly, the SQL Server uses UTF-16 as the encoding for the XML data type, casting from any other encoding will fail with an error. To bypass this, use OPENROWSET(BULK, [FILE_PATH], SINGLE_BLOB) without any typecast, to directly load the data into the destination table as this ignores any encoding specified in the source file.

Import example using XQuery:
USE tempdb;
GO
DECLARE @XMLTABLE TABLE
(
XML_ID INT IDENTITY(1,1) PRIMARY KEY CLUSTERED NOT NULL
,XML_DATA XML NOT NULL
);

INSERT INTO @XMLTABLE (XML_DATA)
SELECT BulkColumn FROM OPENROWSET
(
BULK
'C:\ImportXML\XMLDATA01.xml'
,SINGLE_BLOB
) AS IMPXML
UNION ALL
SELECT BulkColumn FROM OPENROWSET
(
BULK
'C:\ImportXML\XMLDATA02.xml'
,SINGLE_BLOB
) AS IMPXML

SELECT
XT.XML_ID
,PATI.ENT.value('id[1]' ,'INT') AS PATIENT_ID
,PATI.ENT.value('name[1]' ,'NVARCHAR(128)') AS PATIENT_NAME
,PATI.ENT.value('birthdate[1]','DATE') AS PATIENT_BIRTHDATE
FROM @XMLTABLE XT
OUTER APPLY XT.XML_DATA.nodes('root/patient') AS PATI(ENT);


Cool
AllenMWhite
AllenMWhite
SSC Veteran
SSC Veteran (236 reputation)SSC Veteran (236 reputation)SSC Veteran (236 reputation)SSC Veteran (236 reputation)SSC Veteran (236 reputation)SSC Veteran (236 reputation)SSC Veteran (236 reputation)SSC Veteran (236 reputation)

Group: General Forum Members
Points: 236 Visits: 154
PowerShell is really a more efficient way to work with XML. Transact-SQL has never really been good at handling string data of any sort, and while XQuery is significantly better than OpenXML, PowerShell just runs circles around both of them.

I recently wrote an article demonstrating this at SQLMag.com.
http://sqlmag.com/powershell/use-powershell-load-xml-data-sql-server

Allen



Eirikur Eiriksson
Eirikur Eiriksson
SSCrazy Eights
SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)

Group: General Forum Members
Points: 8868 Visits: 18226
It would be interesting to see the performance of PS when working with sets larger than the 2Gb limits of the XML data type. Cool
AllenMWhite
AllenMWhite
SSC Veteran
SSC Veteran (236 reputation)SSC Veteran (236 reputation)SSC Veteran (236 reputation)SSC Veteran (236 reputation)SSC Veteran (236 reputation)SSC Veteran (236 reputation)SSC Veteran (236 reputation)SSC Veteran (236 reputation)

Group: General Forum Members
Points: 236 Visits: 154
Wouldn't you have the same problem in Transact-SQL, though?



Eirikur Eiriksson
Eirikur Eiriksson
SSCrazy Eights
SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)

Group: General Forum Members
Points: 8868 Visits: 18226
AllenMWhite (4/24/2014)
Wouldn't you have the same problem in Transact-SQL, though?

Yes of course, that is why I am interested in seeing how PS would handle this. Often had to implement all kinds of workarounds when the sets are tens or hundreds of Gbs.
Cool
JunkIt
JunkIt
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1248 Visits: 225
Nice article

I would add that OPENXML is not currently supported in an Azure SQL database, so if you're planning on migrating any time soon you'll want to stick with the XML data type. Given the overhead I've read about using OPENXML, I'm not sure this is something Microsoft ever plans on supporting.



Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search