SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Returning Multiple Unrelated Tables in Single XML Output From Stored Proc


Returning Multiple Unrelated Tables in Single XML Output From Stored Proc

Author
Message
blugecko
blugecko
SSC Veteran
SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)

Group: General Forum Members
Points: 257 Visits: 44
Hi There,

I'm quite inexperienced in returning XML from SQL and have only been using single tables to return normal XML in the past.
Now, however, I need to return multiple tables (related or unrelated) in a single XML File for Exporting to another program.

Something like:


SELECT * FROM Products
SELECT * FROM Colours
SELECT * FROM Sizes
FOR XML AUTO, ROOT, ELEMENTS



Obviously the UNION operator is not going to work here so how would I need to write my T-SQL statement to return the following XML Hierarchy?


<root>
<Products>
<...>
</Products>
<Colours>
<...>
</Colours>
<Sizes>
<...>
</Sizes>
</root>



Any help will be appreciated. I've scoured the internet using keywords I think would return some result but, alas, clearly I'm not using the right keywords :-) so I'm hoping someone could point me in the right direction or perhaps even be so kind as to post the solution and save me from forced medical early retirement...

Thanks in advance.

Kind Regards,
Riaan
Sean Lange
Sean Lange
SSC Guru
SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)

Group: General Forum Members
Points: 101402 Visits: 18184
riaan-777462 (10/26/2012)
Hi There,

I'm quite inexperienced in returning XML from SQL and have only been using single tables to return normal XML in the past.
Now, however, I need to return multiple tables (related or unrelated) in a single XML File for Exporting to another program.

Something like:


SELECT * FROM Products
SELECT * FROM Colours
SELECT * FROM Sizes
FOR XML AUTO, ROOT, ELEMENTS



Obviously the UNION operator is not going to work here so how would I need to write my T-SQL statement to return the following XML Hierarchy?


<root>
<Products>
<...>
</Products>
<Colours>
<...>
</Colours>
<Sizes>
<...>
</Sizes>
</root>



Any help will be appreciated. I've scoured the internet using keywords I think would return some result but, alas, clearly I'm not using the right keywords :-) so I'm hoping someone could point me in the right direction or perhaps even be so kind as to post the solution and save me from forced medical early retirement...

Thanks in advance.

Kind Regards,
Riaan


I would split this into three procs instead of trying to do this in a single one.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
blugecko
blugecko
SSC Veteran
SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)

Group: General Forum Members
Points: 257 Visits: 44
Thanks for the quick reply Sean.

The above is an example only, there are 14 tables in total and the end-user will be dragging and dropping the xml file into a VB application.

I couldn't imagine sending 14 XML files and the user dropping 14 files onto the app on every update.

I could join the xml files during the export, but I'm very sure there must be a simpler solution from SQL.

I appreciate your input :-)

Kind Regards,
Riaan
blugecko
blugecko
SSC Veteran
SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)

Group: General Forum Members
Points: 257 Visits: 44
Came right with guidance from various sources. Below the solution in case anyone ever wants to do something similar...


DECLARE @TempExportTable TABLE
(
Products XML,
Colours XML,
Sizes XML
)

INSERT INTO @TempExportTable VALUES
(
(SELECT * FROM Products FOR XML AUTO, ELEMENTS),
(SELECT * FROM Colours FOR XML AUTO, ELEMENTS),
(SELECT * FROM Sizes FOR XML AUTO, ELEMENTS)
)

SELECT
Products as '*',
Colours as '*',
Sizes as '*'
from @TempExportTable
FOR XML PATH('ExportList')


sharon.chapman7
sharon.chapman7
Valued Member
Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)

Group: General Forum Members
Points: 52 Visits: 3
Hi,
Can you tell me how to write this code if I only want certain fields from each table? I get errors when I try to select a few fields to insert into the temp table.

Thanks,
Sharon

PS thanks for posting this code, it was really helpful and I didn't see where anyone else posted code to combine two unrelated tables into one xml file.
Sean Lange
Sean Lange
SSC Guru
SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)

Group: General Forum Members
Points: 101402 Visits: 18184
sharon.chapman7 (11/19/2012)
Hi,
Can you tell me how to write this code if I only want certain fields from each table? I get errors when I try to select a few fields to insert into the temp table.

Thanks,
Sharon

PS thanks for posting this code, it was really helpful and I didn't see where anyone else posted code to combine two unrelated tables into one xml file.


I was able to change the select with no problem. All you have to do is change the columns for any of the select statements. What is the error you are getting?

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
blugecko
blugecko
SSC Veteran
SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)

Group: General Forum Members
Points: 257 Visits: 44
sharon.chapman7 (11/19/2012)
Hi,
Can you tell me how to write this code if I only want certain fields from each table? I get errors when I try to select a few fields to insert into the temp table.

Thanks,
Sharon

PS thanks for posting this code, it was really helpful and I didn't see where anyone else posted code to combine two unrelated tables into one xml file.


Hi Sharon,
I would simply list the columns in each of the SELECT statements.

For instance (taking my example):


DECLARE @TempExportTable TABLE
(
Products XML,
Colours XML,
Sizes XML
)

INSERT INTO @TempExportTable VALUES
(
(SELECT ProductID, PR_Description FROM Products FOR XML AUTO, ELEMENTS),
(SELECT ColourID, CO_Description FROM Colours FOR XML AUTO, ELEMENTS),
(SELECT SizeID, SI_Description FROM Sizes FOR XML AUTO, ELEMENTS)
)

SELECT
Products as '*',
Colours as '*',
Sizes as '*'
from @TempExportTable
FOR XML PATH('ExportList')



I would, of course use the column names you assigned to your tables as they would not be the same :-D

Kind Regards,
Riaan
sharon.chapman7
sharon.chapman7
Valued Member
Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)

Group: General Forum Members
Points: 52 Visits: 3
Thank you for your quick reply. This has been very helpful.

Sharon
Tech Bang
Tech Bang
SSC Rookie
SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)

Group: General Forum Members
Points: 42 Visits: 40
I'm looking for a similar solution, but instead of the 3 select statements, the values will come from 3 stored procs. I tried replacing the procs, get error.

INSERT INTO #TempExportTable VALUES
EXEC ('
EXEC [dbo].[spGetProductsDesc] @tId FOR XML AUTO, ELEMENTS;
EXEC [dbo].[spGetColoursDesc] @tId FOR XML AUTO, ELEMENTS;
EXEC [dbo].[spGetSizesDesc] @tId FOR XML AUTO, ELEMENTS;
');


Any help?

DECLARE @TempExportTable TABLE
(
Products XML,
Colours XML,
Sizes XML
)

INSERT INTO @TempExportTable VALUES
(
(SELECT * FROM Products FOR XML AUTO, ELEMENTS),
(SELECT * FROM Colours FOR XML AUTO, ELEMENTS),
(SELECT * FROM Sizes FOR XML AUTO, ELEMENTS)
)

SELECT
Products as '*',
Colours as '*',
Sizes as '*'
from @TempExportTable
FOR XML PATH('ExportList')
blugecko
blugecko
SSC Veteran
SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)SSC Veteran (257 reputation)

Group: General Forum Members
Points: 257 Visits: 44
Tech Bang (2/27/2016)
I'm looking for a similar solution, but instead of the 3 select statements, the values will come from 3 stored procs. I tried replacing the procs, get error.

INSERT INTO #TempExportTable VALUES
EXEC ('
EXEC [dbo].[spGetProductsDesc] @tId FOR XML AUTO, ELEMENTS;
EXEC [dbo].[spGetColoursDesc] @tId FOR XML AUTO, ELEMENTS;
EXEC [dbo].[spGetSizesDesc] @tId FOR XML AUTO, ELEMENTS;
');


Any help?

DECLARE @TempExportTable TABLE
(
Products XML,
Colours XML,
Sizes XML
)

INSERT INTO @TempExportTable VALUES
(
(SELECT * FROM Products FOR XML AUTO, ELEMENTS),
(SELECT * FROM Colours FOR XML AUTO, ELEMENTS),
(SELECT * FROM Sizes FOR XML AUTO, ELEMENTS)
)

SELECT
Products as '*',
Colours as '*',
Sizes as '*'
from @TempExportTable
FOR XML PATH('ExportList')


Hi Tech Bang,

I would suggest either changing the Stored Procs to a User-Defined-Function which returns a Table:
e.g.
CREATE FUNCTION MyProc()
RETURNS TABLE AS
RETURN (SELECT * FROM MyTable)

Or using OpenQuery:

e.g.
INSERT INTO @TempExportTable VALUES
(
(SELECT * FROM OPENQUERY(YOURSERVERNAME, 'EXEC spGetProductsDesc @tId') FOR XML AUTO, ELEMENTS),
(SELECT * FROM OPENQUERY(YOURSERVERNAME, 'EXEC spGetColoursDesc @tId') FOR XML AUTO, ELEMENTS),
(SELECT * FROM OPENQUERY(YOURSERVERNAME, 'EXEC spGetSizesDesc @tId') FOR XML AUTO, ELEMENTS)
)
...

I haven't tested the code but should put you on the right track :-)

Regards,
Riaan
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