Archive
Posts Tagged ‘read XML’
Save XML in a file | Read XML from a file (in SQL Server)
October 20, 2011
6 comments
USE [AdventureWorks] GO -- Save XML records to a file: DECLARE @fileName VARCHAR(50) DECLARE @sqlStr VARCHAR(1000) DECLARE @sqlCmd VARCHAR(1000) SET @fileName = 'E:\SQL_Queries\test.xml' SET @sqlStr = 'select TOP 50 [ContactID], [Title], [FirstName], [MiddleName], [LastName], [Suffix], [EmailAddress], [Phone] from AdventureWorks.Person.Contact FOR XML PATH(''Contact''), ROOT(''Person.Contact'')' SET @sqlCmd = 'bcp "' + @sqlStr + '" queryout ' + @fileName + ' -w -T' EXEC xp_cmdshell @sqlCmd
Progress:-
NULL
Starting copy...
NULL
6 rows copied.
Network packet size (bytes): 4096
Clock Time (ms.) Total : 15 Average : (400.00 rows per sec.)
NULL
Check the file in the directory set above in @filename variable.
Now we will see how can we read the XML file saved above. Will store the XML in into a SQL Server XML variable
and query it with SELECT statement:
DECLARE @xmlStr XML -- Storing XML records into a XML variable: SELECT @xmlStr = BulkColumn FROM OPENROWSET(BULK 'E:\SQL_Queries\test.xml', SINGLE_CLOB) AS X
The above statement gave me ERROR:
SINGLE_CLOB requires a double-byte character set (DBCS) (char) input file. The file specified is Unicode.
Because the XML BCP’d to the file above was saved in unicode format. So use SINGLE_NCLOB instead of SINGLE_CLOB.
SELECT @xmlStr = BulkColumn FROM OPENROWSET(BULK 'E:\SQL_Queries\test.xml', SINGLE_NCLOB) AS X
This again gave me ERROR:
XML parsing: line 1, character 2034, illegal qualified name character
Because the file saved in xml file has CrLf (Carriage Return & Line Feed) in between.
So I removed the CrLf from the XML string as shown below.
SELECT @xmlStr = REPLACE(REPLACE(BulkColumn,CHAR(10),''),CHAR(13),'') FROM OPENROWSET(BULK 'E:\SQL_Queries\test.xml', SINGLE_NCLOB) AS X -- Querying the XML stored in @xmlStr variable with SELECT statement: SELECT T.C.value('ContactID[1]', 'INT') as [ContactID], T.C.value('Title[1]', 'VARCHAR(8)') as [Title], T.C.value('FirstName[1]', 'VARCHAR(50)') as [FirstName], T.C.value('MiddleName[1]', 'VARCHAR(50)') as [MiddleName], T.C.value('LastName[1]', 'VARCHAR(50)') as [LastName], T.C.value('Suffix[1]', 'VARCHAR(10)') as [Suffix], T.C.value('EmailAddress[1]', 'VARCHAR(50)') as [EmailAddress], T.C.value('Phone[1]', 'VARCHAR(50)') as [Phone] FROM @xmlStr.nodes('//Person.Contact/Contact') as T(C)
Categories: XML
BCP, OPENROWSET, read XML, save XML, SINGLE_BLOB, SINGLE_CLOB, SINGLE_NCLOB, XML