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


XML Query Help


XML Query Help

Author
Message
inayatkhan
inayatkhan
SSC Rookie
SSC Rookie (33 reputation)SSC Rookie (33 reputation)SSC Rookie (33 reputation)SSC Rookie (33 reputation)SSC Rookie (33 reputation)SSC Rookie (33 reputation)SSC Rookie (33 reputation)SSC Rookie (33 reputation)

Group: General Forum Members
Points: 33 Visits: 156
I have four tables and I want to create one XML file. I provided the temp tables with data and expected output.

create table #ZDL(ZLN bigint, ZTLA int, ZMR decimal, ZCLS varchar(20), ZPITIP money)
insert into #ZDL values(1234, 200000, 8.5, 'CART', 1500.00)

create table #ZBL(ZLN bigint, ZBN varchar(50), ZFN varchar(20), ZMN varchar(8), ZLL varchar(20))
insert into #ZBL values(1234, 'TEST Test', 'TEST', null, 'Test')

create table #ZCC(ZLN bigint, ZSN int, ZCE int)
insert into #ZCC values(1234, 1, 4)

create table #ZP(ZLN bigint, ZPT varchar(50), ZPP int, ZNU int)
insert into #ZP values(1234, 'Attached', 6500, 3)


Expected XML Result should be:
<TEST_DATA xmlns="http://www.TestData.com/Schema/Test" xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" xsi:schemaLocation="http://www.TestData.com/Schema/Test_Schema.xsd">
<KEY _Name="ZID" _Value="789" _ID="ZID"/>
<ZL>
<ZLN>1234</ZLN>
<ZTLA>200000</ZTLA>
<ZMR>8.5</ZMR>
<ZCLS>CART</ZCLS>
<ZPITIP>1500.00</ZPITIP>
</ZL>   
<ZBS>
<ZB>
<ZBN>TEST Test</ZBN>
<ZFN>TEST</ZFN>
<ZMN></ZMN>
<ZLL>Test</ZLL>
</ZB>
</ZBS>
<ZCC>
<ZC>
<ZSN>1</ZSN>
<ZCE>4</ZCE>
</ZC>
</ZCC>   
<ZP>
<ZPT>Attached</ZPT>
<ZPP>6500</ZPP>
<ZNU>3</ZNU>   
</ZP>
</TEST_DATA>

Thanks
Evil Kraig F
Evil Kraig F
SSCertifiable
SSCertifiable (5.7K reputation)SSCertifiable (5.7K reputation)SSCertifiable (5.7K reputation)SSCertifiable (5.7K reputation)SSCertifiable (5.7K reputation)SSCertifiable (5.7K reputation)SSCertifiable (5.7K reputation)SSCertifiable (5.7K reputation)

Group: General Forum Members
Points: 5689 Visits: 7660
I have a similar requirement for a 3rd party app I need to interface with. The most effective way I know of to do this is to append the XML components to each other in a final output. Here's an example of one of my procs:



CREATE PROCEDURE <procname>
WITH EXECUTE AS CALLER
AS

SET NOCOUNT ON;
SET FMTONLY OFF;

WHILE 1=0
BEGIN
   SELECT CONVERT( VARCHAR(MAX), NULL) AS Result
END

DECLARE @ShellAccounts_Standard_i XML
DECLARE @ShellAccounts_WTFSC_i XML
DECLARE @ShellAccounts_Standard_u XML
DECLARE @ShellAccounts_WTFSC_u XML

-- We will build out the Portfolio Shell Accounts for
-- new client entries here.
SELECT @ShellAccounts_standard_i =
(
--Query1
FOR XML PATH ('Account')
)

SELECT @ShellAccounts_WTFSC_i =
(
--query2
FOR XML PATH ('Account')
)

SELECT @ShellAccounts_standard_u =
(
--query3
FOR XML PATH ('Account')
)

SELECT @ShellAccounts_WTFSC_u =
(
--query4
FOR XML PATH ('Account')
)





SELECT
      --Header
'<?xml version="1.0" encoding="Windows-1252" ?>'
      + '<ROOT>'
+ '<Header FileDate="' + CONVERT( VARCHAR(20), GETDATE(), 101) + '" />'
+ '<Body DataType="Account">'

      -- Body
      + CONVERT( VARCHAR(MAX), ISNULL( @ShellAccounts_Standard_i, ''))
      + CONVERT( VARCHAR(MAX), ISNULL( @ShellAccounts_WTFSC_i, ''))
      + CONVERT( VARCHAR(MAX), ISNULL( @ShellAccounts_Standard_u, ''))
      + CONVERT( VARCHAR(MAX), ISNULL( @ShellAccounts_WTFSC_u, ''))


      -- Footer
      + '</Body>'
      + CONVERT( VARCHAR(MAX) ,
            (SELECT 'Account' AS [@DataType], SUM(cnt) AS [@RecordCount]
               FROM
                  (SELECT COUNT(*) AS cnt
                  FROM   @ShellAccounts_Standard_i.nodes('Account') cnt(nd)
                  UNION ALL
                  SELECT COUNT(*) AS cnt
                  FROM   @ShellAccounts_WTFSC_i.nodes('Account') cnt(nd)
                  UNION ALL
                  SELECT COUNT(*) AS cnt
                  FROM   @ShellAccounts_Standard_u.nodes('Account') cnt(nd)
                  UNION ALL
                  SELECT COUNT(*) AS cnt
                  FROM   @ShellAccounts_WTFSC_u.nodes('Account') cnt(nd)
                  Wink AS drv
               FOR XML PATH ( 'Trailer')
               Wink
            Wink
      + '</ROOT>'
   AS Result

SET NOCOUNT OFF;

GO



Obviously some of this is obfuscated, but if you change your PATH('') between queries and then append it like I have (instead of everything being 'Account'), you should get to your results.

This is the simplest method I've found to deal with XML creation when you need footers and the like, or need to change node structure between different components.


- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
inayatkhan
inayatkhan
SSC Rookie
SSC Rookie (33 reputation)SSC Rookie (33 reputation)SSC Rookie (33 reputation)SSC Rookie (33 reputation)SSC Rookie (33 reputation)SSC Rookie (33 reputation)SSC Rookie (33 reputation)SSC Rookie (33 reputation)

Group: General Forum Members
Points: 33 Visits: 156
Thanks!
wBob
wBob
SSC Rookie
SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)

Group: General Forum Members
Points: 31 Visits: 576
I would approach that more like this:

DECLARE @xml XML 

SET @xml = (
SELECT
   (
   SELECT
      'ZID' AS "@_Name",
      '789' AS "@_Value",
      'ZID' AS "@_ID"
   FOR XML PATH('KEY'), TYPE
   Wink,
   (
   SELECT
      ZLN,
      ZTLA,
      ZMR,
      ZCLS,
      ZPITIP
   FROM #ZDL ZL
   FOR XML AUTO, ELEMENTS, TYPE
   Wink,
   (
   SELECT
      ZBN,
      ZFN,
      ISNULL(ZMN,'') AS ZMN,
      ZLL
   FROM #ZBL ZB
   FOR XML AUTO, ELEMENTS, TYPE
   Wink AS ZBS,
   (
   SELECT
      ZSN,
      ZCE
   FROM #ZCC ZC
   FOR XML AUTO, ELEMENTS, TYPE
   Wink AS ZCC,
   (
   SELECT
      ZPT,
      ZPP,
      ZNU
   FROM #ZP ZL
   FOR XML AUTO, ELEMENTS, TYPE
   Wink
FOR XML PATH(''), ELEMENTS, ROOT('TEST_DATA')
)

-- Fix up the header; NVARCHAR hack
SET @xml = REPLACE( CAST( @xml AS NVARCHAR(MAX) ), '<TEST_DATA>', '<TEST_DATA xmlns="http://www.TestData.com/Schema/Test">' )

SELECT @xml x


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