Simple way to Import XML Data into SQL Server with T-SQL

By:   |   Updated: 2022-02-25   |   Comments (17)   |   Related: > XML


Problem

XML is a data format used to share data in a form that can be easily used and shared. There is often the need import XML files into SQL Server which can be done several ways and in this tip we will look at a simple way to do this using just T-SQL commands.

Solution

There many possible ways to perform this type of import and in this tip we will show how this can be done using T-SQL and OPENROWSET to read the XML data and load into a SQL Server table.  In order for you to understand it better, let’s walk through an example.

Step 1 – Create table to store imported data

Let’s create a simple table that’ll store the data of our customers.

USE mssqltips_db
GO

CREATE TABLE [CUSTOMERS_TABLE](
    [ID] [int] IDENTITY(1,1) NOT NULL,
    [DOCUMENT] [varchar](20) NOT NULL,
    [NAME] [varchar](50) NOT NULL,
    [ADDRESS] [varchar](50) NOT NULL,
    [PROFESSION] [varchar](50) NOT NULL,
 CONSTRAINT [CUSTOMERS_PK] PRIMARY KEY ([Id])
)
GO

Step 2 - Create Sample XML File

Below is sample XML data.  You can use this as is or modify for your own tests. I copied this data and stored in a file named MSSQLTIPS_XML.xml.

<?xml version="1.0" encoding="utf-8"?>
<Customers>
  <Customer>
    <Document>000 000 000</Document>
    <Name>Mary Angel</Name>
    <Address>Your City, YC 1212</Address>
    <Profession>Systems Analyst</Profession>
  </Customer>
  <Customer>
    <Document>000 000 001</Document>
    <Name>John Lenon</Name>
    <Address>Your City, YC 1212</Address>
    <Profession>Driver</Profession>
  </Customer>
  <Customer>
    <Document>000 000 002</Document>
    <Name>Alice Freeman</Name>
    <Address>Your City, YC 1212</Address>
    <Profession>Architect</Profession>
  </Customer>
  <Customer>
    <Document>000 000 003</Document>
    <Name>George Sands</Name>
    <Address>Your City, YC 1212</Address>
    <Profession>Doctor</Profession>
  </Customer>
  <Customer>
    <Document>000 000 004</Document>
    <Name>Mark Oliver</Name>
    <Address>Your City, YC 1212</Address>
    <Profession>Writer</Profession>
  </Customer>
</Customers>

Step 3 – Importing the XML data file into a SQL Server Table

Now all we need is to make SQL Server read the XML file and import the data via the OPENROWSET function. This function is native to T-SQL and allows us to read data from many different file types through the BULK import feature, which allows the import from lots of file types, like XML.

Here is the code to read the XML file and to INSERT the data into a table.

INSERT INTO CUSTOMERS_TABLE (DOCUMENT, NAME, ADDRESS, PROFESSION)
SELECT
   MY_XML.Customer.query('Document').value('.', 'VARCHAR(20)'),
   MY_XML.Customer.query('Name').value('.', 'VARCHAR(50)'),
   MY_XML.Customer.query('Address').value('.', 'VARCHAR(50)'),
   MY_XML.Customer.query('Profession').value('.', 'VARCHAR(50)')
FROM (SELECT CAST(MY_XML AS xml)
      FROM OPENROWSET(BULK 'C:\temp\MSSQLTIPS_XML.xml', SINGLE_BLOB) AS T(MY_XML)) AS T(MY_XML)
      CROSS APPLY MY_XML.nodes('Customers/Customer') AS MY_XML (Customer);
  • The first thing we are doing is a simple INSERT into our table CUSTOMERS_TABLE.
  • The columns in the SELECT are pulled from the alias we created named MY_XML and we are querying each element of the Customer node.
  • The FROM clause is derived by using the OPENROWSET operation using the BULK option and the SINGLE_BLOB option to have the data returned from the XML file into a single column and row. The function nodes() along with CROSS APPLY allows navigation through the XML element’s in order to get all of Customer objects properly encapsulated.

Step 4 - Check the Imported XML Data

After the insert, you can query the table to check the results.

SELECT * FROM CUSTOMERS_TABLE
xml file import query results
Next Steps


sql server categories

sql server webinars

subscribe to mssqltips

sql server tutorials

sql server white papers

next tip



About the author
MSSQLTips author Diogo Souza Diogo Souza has been passionate about clean code, data manipulation, software design and development for almost ten years.

This author pledges the content of this article is based on professional experience and not AI generated.

View all my tips


Article Last Updated: 2022-02-25

Comments For This Article




Thursday, February 1, 2024 - 11:37:10 AM - Klaas Ploegman Back To Top (91912)
I've tried the original proposal as well as the modified proposal of Mikael Eriksson, with my own data, but it does not work.
I've looked at the examples multiple times, but do not see any difference.
Could you please help?

Wednesday, September 13, 2023 - 3:00:55 AM - JL Back To Top (91551)
I recreated the sample. Didn't work for me. Got "Customer is not a invalid function, property, or field" in MY_XML.Customer.query.

No big. Moving on.

Friday, October 21, 2022 - 5:25:37 AM - Filip Back To Top (90623)
I see now, thanks.

I tried to run the commands but got syntax error in the following statement at ".value":

SELECT
MY_XML.Customer.query('Document').value('.', 'VARCHAR(20)'),

Any idea?

Monday, October 17, 2022 - 10:36:25 AM - Greg Robidoux Back To Top (90609)
Hi Filip,

It is a little confusing.

This is the query the tip is using.

INSERT INTO CUSTOMERS_TABLE (DOCUMENT, NAME, ADDRESS, PROFESSION)
SELECT
MY_XML.Customer.query('Document').value('.', 'VARCHAR(20)'),
MY_XML.Customer.query('Name').value('.', 'VARCHAR(50)'),
MY_XML.Customer.query('Address').value('.', 'VARCHAR(50)'),
MY_XML.Customer.query('Profession').value('.', 'VARCHAR(50)')
FROM (SELECT CAST(MY_XML AS xml)
FROM OPENROWSET(BULK 'C:\temp\MSSQLTIPS_XML.xml', SINGLE_BLOB) AS T(MY_XML)) AS T(MY_XML)
CROSS APPLY MY_XML.nodes('Customers/Customer') AS MY_XML (Customer);


The subquery below is part of the above query and is given an alias name using this part of the above query "AS MY_XML (Customer)".

SELECT CAST(MY_XML AS xml)
FROM OPENROWSET(BULK 'C:\temp\MSSQLTIPS_XML.xml', SINGLE_BLOB) AS T(MY_XML)) AS T(MY_XML)
CROSS APPLY MY_XML.nodes('Customers/Customer'


This is done so the query part below can pull data from the subquery using the alias name "AS MY_XML (Customer)".

SELECT
MY_XML.Customer.query('Document').value('.', 'VARCHAR(20)'),
MY_XML.Customer.query('Name').value('.', 'VARCHAR(50)'),
MY_XML.Customer.query('Address').value('.', 'VARCHAR(50)'),
MY_XML.Customer.query('Profession').value('.', 'VARCHAR(50)')

Monday, October 17, 2022 - 10:01:33 AM - Filip Back To Top (90608)
Hi,

I still do not understand how the select would work if the alias is not previously created.

Tuesday, October 11, 2022 - 11:29:31 AM - Greg Robidoux Back To Top (90588)
Hi Filip,

You should be able to just run each set of code and this should work.

For the "alias" info, he is just explaining the code which is using a subquery to gather the data.

Let me know if you have more questions and I can see if I can help.

Tuesday, October 11, 2022 - 10:25:39 AM - Filip Back To Top (90587)
It would be nice to have all the steps described here. For people who are doind it for the first time becomes a little confusing when you mention an alias but does not show how to do it.

Thursday, March 17, 2022 - 9:32:24 AM - Greg Robidoux Back To Top (89895)
Hi Marcin,

I don't think that is possible. If I find something that says it can be done I will add another comment.

-Greg

Thursday, March 17, 2022 - 7:54:18 AM - Marcin Bednarek Back To Top (89893)
is it possible to import XML data directly from URL ? or I've to download if to disk first ?

Thursday, May 6, 2021 - 1:38:44 AM - Medyanik Yevhen Back To Top (88652)
What does MY_XML actually means? I don't get it.

Friday, July 10, 2020 - 1:48:38 PM - Clay Back To Top (86119)

Thank you so much for this.  It's clear, concise and works!


Thursday, March 26, 2020 - 12:37:14 PM - Chris Morse Back To Top (85196)

Very clear instructions ... Thank you.  

I'll post back and let you know if I made it work correctly.


Thursday, October 17, 2019 - 4:49:35 AM - Aamir Back To Top (82804)

How to load below XML data into SQL?

 

<?xml version="1.0" encoding="utf-8"?> 

<DataTable xmlns="SmarttraceWS"> 

  <xs:schema id="NewDataSet" xmlns="" xmlns:xs="http://www.w3.org/2001/XMLSchema" xmlns:msdata="urn:schemas-microsoft-com:xml-msdata"> 

    <xs:element name="NewDataSet" msdata:IsDataSet="true" msdata:MainDataTable="ActivityRecords" msdata:UseCurrentLocale="true"> 

      <xs:complexType> 

        <xs:choice minOccurs="0" maxOccurs="unbounded"> 

          <xs:element name="ActivityRecords"> 

            <xs:complexType> 

              <xs:sequence> 

                <xs:element name="ReferenceID" type="xs:long" minOccurs="0" /> 

                <xs:element name="IMEI" type="xs:string" minOccurs="0" /> 

                <xs:element name="Asset" type="xs:string" minOccurs="0" /> 

                <xs:element name="Driver" type="xs:string" minOccurs="0" /> 

                <xs:element name="DateTime" type="xs:string" minOccurs="0" /> 

 

              </xs:sequence> 

            </xs:complexType> 

          </xs:element> 

        </xs:choice> 

      </xs:complexType> 

    </xs:element> 

  </xs:schema> 

  <diffgr:diffgram xmlns:msdata="urn:schemas-microsoft-com:xml-msdata" xmlns:diffgr="urn:schemas-microsoft-com:xml-diffgram-v1"> 

    <DocumentElement xmlns=""> 

      <ActivityRecords diffgr:id="ActivityRecords1" msdata:rowOrder="0"> 

        <ReferenceID>2620443016</ReferenceID> 

        <IMEI>013795001360346</IMEI> 

        <Asset>L-93745</Asset> 

        <Driver>N/A</Driver> 

        <DateTime>2019-10-14 12:00:35</DateTime> 

              </ActivityRecords> 

    </DocumentElement> 

  </diffgr:diffgram> 

</DataTable>

shareeditdelete


Wednesday, September 11, 2019 - 4:59:49 AM - Arpan Back To Top (82353)

I get the following error

Cannot bulk load because the file "D:\MSSQLTIPS_XML.xml" could not be opened. Operating system error code 21(The device is not ready.).


Tuesday, January 8, 2019 - 11:07:44 AM - Tom Back To Top (78670)

 If the XML file contains a reference to a DTD file, you will need to change the CAST to a CONVERT to avoid the "Cannot parse..." error.  As:

SELECT CONVERT(XML, MY_XML,2)  --CAST(MY_XML AS xml)
      FROM OPENROWSET(BULK ...


Thursday, October 11, 2018 - 10:23:46 AM - Eirikur Eiriksson Back To Top (77924)

Mikael Eriksson beat me to it!

The text() function prevents the result set from being constructed as an XML, removes at least two blocking operators from the execution plan.


Wednesday, October 10, 2018 - 2:30:07 AM - Mikael Eriksson Back To Top (77911)

Hi!

There are some issues with your code that makes it go really slow. Specificcly the cast to XML and the use of the query() function. 

Add a couple of hundred Customer nodes to your XML and compare duration between your version and a rewritten version below. 

On my machine for 300 Customer elements, duration goes from 8 seconds down to 18 millisecond.

declare @X xml;
select @X = T.MY_XML
from openrowset(bulk 'D:\slask\MSSQLTIPS_XML.xml', single_blob) as T(MY_XML)
select
   MY_XML.Customer.value('(Document/text())[1]', 'VARCHAR(20)'),
   MY_XML.Customer.value('(Name/text())[1]', 'VARCHAR(50)'),
   MY_XML.Customer.value('(Address/text())[1]', 'VARCHAR(50)'),
   MY_XML.Customer.value('(Profession/text())[1]', 'VARCHAR(50)')
from @X.nodes('Customers/Customer') AS MY_XML (Customer);














get free sql tips
agree to terms