October 18, 2009 at 10:26 am
Hello:
I am new to SQl server. Here is my question and hope some one can help me.
We have a database containingg the following structure: GrandParent (GP),parent(p1,p2,p3), child tables.
My task is to create an XML out of the tables taking given a record in GP, it should give me the whole hierarchy of all tables underneath it "like a tree structure" if you would call it.
1. I have an XSD how my XML should look like. Can I register this XSD with the SQL server and ask it to generate a XML confirming to the XSD I have?
The database is having very deep hierarchy and I appreciate your help.
My plan is to use VB.net with minimal coding on the client side. please let me know.
October 19, 2009 at 7:56 am
ucbus 92278 (10/18/2009)
Hello:I am new to SQl server. Here is my question and hope some one can help me.
We have a database containingg the following structure: GrandParent (GP),parent(p1,p2,p3), child tables.
My task is to create an XML out of the tables taking given a record in GP, it should give me the whole hierarchy of all tables underneath it "like a tree structure" if you would call it.
1. I have an XSD how my XML should look like. Can I register this XSD with the SQL server and ask it to generate a XML confirming to the XSD I have?
Yes, you can register it. No, you can't just tell SQL Server to create the XML based upon the schema. Your SQL query is doing all of the work.
My plan is to use VB.net with minimal coding on the client side. please let me know.
Some process will still have to do the work. Either SQL Server via a complex query creating XML or the middle-tier (client) taking simple result sets and then transforming it into XML. Although you can create complex hierarchical XML from SQL Server, the latter may be more "efficient".
XML Support in Microsoft SQL Server 2005
http://msdn.microsoft.com/en-us/library/ms345117(SQL.90).aspx
XML Options in Microsoft SQL Server 2005
http://msdn.microsoft.com/en-us/library/ms345110(SQL.90).aspx
What's New in FOR XML in Microsoft SQL Server 2005
http://msdn.microsoft.com/en-us/library/ms345137(SQL.90).aspx
XML Indexes in SQL Server 2005
http://msdn.microsoft.com/en-us/library/ms345121(SQL.90).aspx
XML Best Practices for Microsoft SQL Server 2005
http://msdn.microsoft.com/en-us/library/ms345115(SQL.90).aspx
October 20, 2009 at 7:09 am
Mauve:
Thanks for the response.
Just to eloborate on my requirement. My XML/XSD would follow the following format
-------------
<message>
<message header>
<messsage ID>
<date time >
< etc etc>
</message header>
<message body>
<grand parent>
<parent1>
<child1>
<child 2>
</parent1>
<parent2>
<child1>
<child 2>
</parent2>
</grand parent>
</message body>
</message>---------------------
Now, I have created the same structure in SQL Server tables and loaded the data. Now my task is to get the data from the tables ( which exactly match my XML tags) in the XML format
I have tried to use "FOR XML" tag by creating a view of the data, However this resulted in multiple rows in a FLAT structure. To get the XML in the format I needed, I would have to use XSLT transformation I guess.
Second option is to use "XML Views". I find MS documents on using XDRs to create XML Views. However I am not sure how to create XDRs given that I have XSD and matching relational database structure. Can any one help with the approach. Now how to get the data tree specific to say a particular record, in my case a <message>?
Third, Object Relational Mapping is something that could be helpful. I am not sure what can be used in case of .NET and VB.net. ?
Please let me know what is the ideal approach given the above scenario.
October 20, 2009 at 8:31 am
In our use of XML as a data parsing mechanism from/to our .Net layer and SQL Server 2005 we are using traditional relational structures (tables) to hold the data. The stored procedures take the input XML and selectively extract, using XQuery syntax, data values from it for DML operations against the tables. I.e., it is only used to simplify the data parameters to the stored procedures.
Similarly, we construct a single XML document from the relational structure, using FOR XML PATH, to return to the .Net layer vs. numerous result sets (i.e., a .Net DataSet) which the .Net layer would have to iterate through. See (one of) Jacob Sebastian's articles for some sample syntax: http://www.sqlservercentral.com/articles/XML/62289/
We are not, as you are proposing, attempting to use SQL Server 2005 as an object relational database utilizing XML and Annotated XSD Schemas. Therefore, I cannot offer any further assistance in this area.
October 21, 2009 at 4:11 am
ucbus 92278 (10/20/2009)I have tried to use "FOR XML" tag by creating a view of the data, However this resulted in multiple rows in a FLAT structure. To get the XML in the format I needed, I would have to use XSLT transformation I guess.
Not necessarily. You're making a couple of assumptions here. Just because the XML looks flat doesn't mean that the XSD file won't read it. I have XML files like that which I import into SQL Server using SSIS with an XSD file all the time. It works just fine.
Also, there are three different versions of the FOR XML command. Are you sure you tried all three of them to get the exact format you wanted? (aside from the flat issue, that is).
If you don't want to use SSMS for your results, create an SSRS report and a subscription to that report that exports into an XML format. I've done that quite often and it works amazingly well. Even if it looks "flat", an XSD file will read it. I know this for a fact.
October 21, 2009 at 6:41 am
For those of us who don't know enough yet, what exactly do you mean by the XML file looking "flat"? (anyone)
Thanks,
Jon
---------------------------------------------------------
How best to post your question[/url]
How to post performance problems[/url]
Tally Table:What it is and how it replaces a loop[/url]
"stewsterl 80804 (10/16/2009)I guess when you stop and try to understand the solution provided you not only learn, but save yourself some headaches when you need to make any slight changes."
October 21, 2009 at 6:50 am
I'm assuming "flat" means that the XML is all on one line with no pretty carriage returns between each data element. Sort of like:
<column1>2adfad</column1><column2>adfeoue</column2><column3>etouen</column3>
If that's not what the OP means by the term, then please correct me.
December 3, 2009 at 8:49 am
When I said "flat" I meant from the "relational structure" point of view. For example you have a Parent and two children, then you can represent this by
parent1, child1
parent1, child 2
or parent1,child1,child2
anyways, I have resolved it by using "for xml path" and using "Select sub-queris".
December 3, 2009 at 8:58 am
Could you post some sample code for the resolution so that people who need this in the future can better understand your solution?
December 4, 2009 at 8:11 am
Sure. I have posted the sample code at http://www.sqlservercentral.com/Forums/Topic827863-21-1.aspx. I could as well post it here, but why to waste storage?
December 8, 2009 at 4:43 am
That link just shows another question. It doesn't actually show what you did for a final solution.
But if you post the final solution in either thread, then reference that solution with a link, that would work.
December 11, 2009 at 3:13 pm
OK. I have posted the solution in post #4. But reproducing here.
---------------------
Script to create tables
---------------------
USE [AdventureWorks]
GO
/****** Object: Table [dbo].[myparent] Script Date: 12/03/2009 15:10:53 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[myparent](
[parentid] [int] NOT NULL,
[pdesc] [nvarchar](10) NULL,
CONSTRAINT [PK_myparent] PRIMARY KEY CLUSTERED
(
[parentid] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[mychild] Script Date: 12/03/2009 15:10:53 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[mychild](
[childid] [int] NOT NULL,
[cdesc] [nvarchar](10) NULL,
[parentid] [int] NULL,
CONSTRAINT [PK_mychild] PRIMARY KEY CLUSTERED
(
[childid] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[mygrandchild] Script Date: 12/03/2009 15:10:53 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[mygrandchild](
[grandchildid] [int] NOT NULL,
[gdesc] [varchar](10) NULL,
[childid] [int] NULL,
CONSTRAINT [PK_mygrandchild] PRIMARY KEY CLUSTERED
(
[grandchildid] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
SET ANSI_PADDING ON
GO
/****** Object: ForeignKey [FK_mychild_myparent] Script Date: 12/03/2009 15:10:53 ******/
ALTER TABLE [dbo].[mychild] WITH CHECK ADD CONSTRAINT [FK_mychild_myparent] FOREIGN KEY([parentid])
REFERENCES [dbo].[myparent] ([parentid])
GO
ALTER TABLE [dbo].[mychild] CHECK CONSTRAINT [FK_mychild_myparent]
GO
/****** Object: ForeignKey [FK_mygrandchild_mygrandchild] Script Date: 12/03/2009 15:10:53 ******/
ALTER TABLE [dbo].[mygrandchild] WITH CHECK ADD CONSTRAINT [FK_mygrandchild_mygrandchild] FOREIGN KEY([childid])
REFERENCES [dbo].[mychild] ([childid])
GO
ALTER TABLE [dbo].[mygrandchild] CHECK CONSTRAINT [FK_mygrandchild_mygrandchild]
GO
--------------------------------
Script to load tables
------------------------------------
USE [AdventureWorks];
SET NOCOUNT ON;
SET XACT_ABORT ON;
GO
BEGIN TRANSACTION;
INSERT INTO [dbo].[myparent]([parentid], [pdesc])
SELECT 1, N'parent1' UNION ALL
SELECT 2, N'parent2' UNION ALL
SELECT 3, N'parent3'
COMMIT;
RAISERROR (N'[dbo].[myparent]: Insert Batch: 1.....Done!', 10, 1) WITH NOWAIT;
GO
USE [AdventureWorks];
SET NOCOUNT ON;
SET XACT_ABORT ON;
GO
BEGIN TRANSACTION;
INSERT INTO [dbo].[mychild]([childid], [cdesc], [parentid])
SELECT 1, N'child1p1', 1 UNION ALL
SELECT 2, N'child2p1', 1 UNION ALL
SELECT 3, N'child3p2', 2
COMMIT;
RAISERROR (N'[dbo].[mychild]: Insert Batch: 1.....Done!', 10, 1) WITH NOWAIT;
GO
USE [AdventureWorks];
SET NOCOUNT ON;
SET XACT_ABORT ON;
GO
BEGIN TRANSACTION;
INSERT INTO [dbo].[mygrandchild]([grandchildid], [gdesc], [childid])
SELECT 1, N'g1c1p1', 1 UNION ALL
SELECT 2, N'g2c1p1', 1 UNION ALL
SELECT 3, N'g3c2p1', 2 UNION ALL
SELECT 4, N'g4c2p1', 2
COMMIT;
RAISERROR (N'[dbo].[mygrandchild]: Insert Batch: 1.....Done!', 10, 1) WITH NOWAIT;
GO
--------------------------
Script to generate XML
--------------------
use adventureworks
SELECT parentid as 'pid'
,pdesc as 'desc'
,(SELECT childid as 'cid'
,cdesc as 'desc'
,(SELECT grandchildid as 'gid'
,gdesc as 'gdesc'
FROM mygrandchild g
INNER JOIN dbo.mychild c1
ON g.childid= c1.childid
Where c1.childid=c.childid
FOR XML PATH ('grandchild'), TYPE)
FROM mychild c
INNER JOIN dbo.myparent p
ON c.parentid = p.parentid
Where p.parentid=p1.parentid
FOR XML PATH ('child'), TYPE)
FROM myparent p1
Where p1.parentid=3
FOR XML PATH('parent'),ELEMENTS, ROOT('tree')
June 4, 2012 at 8:31 am
Hi ucbus,
I landed in your thread when searching for a similar solution. Thanks a lot for your effort and a sample script. However, is there a easy change avaialble in your queries to get the table columns as "Attributes" rather than an "element" in the xml?
Example:-
<parent pid="1" desc="parent1">
<child cid="1" desc="child1p1">
<grandchild gid="1" gdesc="g1c1p1" />
<grandchild gid="2" gdesc="g2c1p1" />
</child>
<child cid="2" desc="child2p1">
<grandchild gid="3" gdesc="g3c2p1" />
<grandchild gid="4" gdesc="g4c2p1" />
</child>
</parent>
Also, i need to store the resulted XML into local hard drive. Please suggest if it can be achieved through stored procedure.
Regards,
Suresh Arumugam
June 4, 2012 at 9:11 am
Suresh Kumar-284278 (6/4/2012)
Hi ucbus,I landed in your thread when searching for a similar solution. Thanks a lot for your effort and a sample script. However, is there a easy change avaialble in your queries to get the table columns as "Attributes" rather than an "element" in the xml?
Example:-
<parent pid="1" desc="parent1">
<child cid="1" desc="child1p1">
<grandchild gid="1" gdesc="g1c1p1" />
<grandchild gid="2" gdesc="g2c1p1" />
</child>
<child cid="2" desc="child2p1">
<grandchild gid="3" gdesc="g3c2p1" />
<grandchild gid="4" gdesc="g4c2p1" />
</child>
</parent>
Also, i need to store the resulted XML into local hard drive. Please suggest if it can be achieved through stored procedure.
Easy. Just prefix the resulting name with an @ sign.
Example:
SELECT
u.user_id AS "@ID",
u.login AS "@Login",
u.email AS "@Email",
u.first_name AS "@FirstName",
u.last_name AS "@LastName",
u.name_first_last AS "@NameFirstLast",
u.name_last_first AS "@NameLastFirst",
...
Note that I enclose the labels with double quotes to ensure the correct XML label (Attribute or Element) as XML is case sensitive.
As for saving to the file system from within T-SQL, I don't think that that is a good idea. Have a client application (PowerShell would be a simple script) return the data back and have it write it to the file system.
June 4, 2012 at 9:52 am
First, I doubt you'll get a response from the original poster on this. If you note the dates, the original conversation was 2 1/2 years ago (December 2009).
Second, output to a file from a stored procedure can be done, but is usually a bad idea. You would do it by calling BCP (documentation here: http://msdn.microsoft.com/en-us/library/ms162802.aspx). This has some security implications, since you would use xp_cmdshell to call BCP.
Alternatively, you could create a .NET CLR object in your database that would write to a file. Again, this has security issues.
More usually, you would use SSIS for import/export tasks, or something else external to SQL Server (like PowerShell).
I would recommend SSIS, but mainly because I'm familiar with it and comfortable with getting jobs done through it. Not because it's better than other options in other ways.
- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread
"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
Viewing 15 posts - 1 through 15 (of 16 total)
You must be logged in to reply to this topic. Login to reply