Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

XML issue converting table to XML Expand / Collapse
Author
Message
Posted Friday, March 01, 2013 10:46 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, April 02, 2014 6:16 AM
Points: 151, Visits: 282
Hi,

Thanks for your help in advance. I am trying to get the following data

CREATE TABLE [dbo].[TABLE_XML1](
[ID] [int] IDENTITY(1,1) NOT NULL,
[TOP_LEVEL_ID] [int] NULL,
[TOP_LEVEL_ITEM] [nvarchar](50) NULL,
[SECOND_LEVEL_ID] [int] NULL,
[SECOND_LEVEL_ITEM] [nvarchar](50) NULL,
[THIRD_LEVEL_ID] [int] NULL,
[THIRD_LEVEL_ITEM] [nvarchar](50) NULL,
[FOURTH_LEVEL_ID] [int] NULL,
[FOURTH_LEVEL_ITEM] [nvarchar](50) NULL,
CONSTRAINT [PK_TABLE_XML1] PRIMARY KEY CLUSTERED
(
[ID] 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 IDENTITY_INSERT [dbo].[TABLE_XML1] ON

GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (1, 294, N'TOP LEVEL TYPE A', 1244, N'SECOND LEVEL ITEM A', 1245, N'THIRD LEVEL ITEM A', 2222, N'FOURTH LEVEL ITEM A')
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (2, 294, N'TOP LEVEL TYPE A', 1252, N'SECOND LEVEL ITEM B', 1245, N'THIRD LEVEL ITEM A', 2223, N'FOURTH LEVEL ITEM B')
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (3, 294, N'TOP LEVEL TYPE A', 1254, N'SECOND LEVEL ITEM C', 1255, N'THIRD LEVEL ITEM B', 2231, N'FOURTH LEVEL ITEM C')
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (4, 294, N'TOP LEVEL TYPE A', 1298, N'SECOND LEVEL ITEM D', 1255, N'THIRD LEVEL ITEM B', 2313, N'FOURTH LEVEL ITEM D')
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (5, 294, N'TOP LEVEL TYPE A', 1302, N'SECOND LEVEL ITEM E', 1303, N'THIRD LEVEL ITEM C', 2318, N'FOURTH LEVEL ITEM E')
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (6, 294, N'TOP LEVEL TYPE A', 1305, N'SECOND LEVEL ITEM F', 1303, N'THIRD LEVEL ITEM C', 2192, N'FOURTH LEVEL ITEM F')
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (7, 656, N'TOP LEVEL TYPE B', 657, N'SECOND LEVEL ITEM G', 27, N'THIRD LEVEL ITEM A', NULL, NULL)
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (8, 656, N'TOP LEVEL TYPE B', 657, N'SECOND LEVEL ITEM G', 638, N'THIRD LEVEL ITEM B', NULL, NULL)
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (9, 656, N'TOP LEVEL TYPE B', 657, N'SECOND LEVEL ITEM G', 939, N'THIRD LEVEL ITEM C', NULL, NULL)
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (10, 656, N'TOP LEVEL TYPE B', 657, N'SECOND LEVEL ITEM G', 939, N'THIRD LEVEL ITEM C', NULL, NULL)
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (11, 656, N'TOP LEVEL TYPE B', 657, N'SECOND LEVEL ITEM G', 939, N'THIRD LEVEL ITEM C', NULL, NULL)
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (12, 656, N'TOP LEVEL TYPE B', 1165, N'SECOND LEVEL ITEM H', 940, N'THIRD LEVEL ITEM D', NULL, NULL)
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (13, 656, N'TOP LEVEL TYPE B', 1165, N'SECOND LEVEL ITEM H', 940, N'THIRD LEVEL ITEM D', NULL, NULL)
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (14, 1234, N'TOP LEVEL TYPE C', 2206, N'SECOND LEVEL ITEM I', NULL, NULL, NULL, NULL)
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (15, 1234, N'TOP LEVEL TYPE C', 2207, N'SECOND LEVEL ITEM J', NULL, NULL, NULL, NULL)
GO
INSERT [dbo].[TABLE_XML1] ([ID], [TOP_LEVEL_ID], [TOP_LEVEL_ITEM], [SECOND_LEVEL_ID], [SECOND_LEVEL_ITEM], [THIRD_LEVEL_ID], [THIRD_LEVEL_ITEM], [FOURTH_LEVEL_ID], [FOURTH_LEVEL_ITEM]) VALUES (16, 1234, N'TOP LEVEL TYPE C', 2208, N'SECOND LEVEL ITEM K', NULL, NULL, NULL, NULL)
GO
SET IDENTITY_INSERT [dbo].[TABLE_XML1] OFF
GO

Into XML

Such that it is structured like

<TOP_LEVEL_ITEM= "TOP LEVEL TYPE A" TOP_LEVEL_ID="294">
<SECOND_LEVEL_ITEM= "SECOND LEVEL ITEM A" SECOND_LEVEL_ID="1244">
<THIRD_LEVEL_ITEM="THIRD LEVEL ITEM A" THIRD_LEVEL_ID="1245">
<FOURTH_LEVEL_ITEM="FOURTH LEVEL ITEM A" FOURTH_LEVEL_ID="2222">
<FOURTH_LEVEL_ITEM="FOURTH LEVEL ITEM b" FOURTH_LEVEL_ID="2223">
</THIRD_LEVEL_ITEM>
<THIRD_LEVEL_ITEM="THIRD LEVEL ITEM B" THIRD_LEVEL_ID="1255">
<FOURTH_LEVEL_ITEM="FOURTH LEVEL ITEM C" FOURTH_LEVEL_ID="2231">
<FOURTH_LEVEL_ITEM="FOURTH LEVEL ITEM D" FOURTH_LEVEL_ID="2313">
</THIRD_LEVEL_ITEM>
</SECOND_LEVEL_ITEM>
</TOP_LEVEL_ITEM>

Any pointers as to how I can achieve this are gratefully appreciated.

Cheers,

Oliver
Post #1425640
Posted Friday, March 01, 2013 1:03 PM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Tuesday, September 03, 2013 8:24 AM
Points: 1,240, Visits: 5,421
First, your XML is not valid. You can only assign values to attributes and you are trying to assign them to the tag.

&lt;TOP_LEVEL_ITEM= "TOP LEVEL TYPE A" TOP_LEVEL_ID="294"&gt;

This needs to be changed to something like

&lt;TOP_LEVEL_ITEM name= "TOP LEVEL TYPE A" TOP_LEVEL_ID="294"&gt;

Second, your data doesn't match the expected results. For instance, you results has id 2223 under 294/1244/1245, but you data has it under 294/1252/1245.

That being said, the most efficient way is probably to use FOR XML EXPLICIT, but most people find that too confusing. Any other method will have to access the table multiple times in order to create the requisite structure.

SELECT DISTINCT Tag, Parent
, t.[TOP_LEVEL_ITEM!1!name], t.[TOP_LEVEL_ITEM!1!id]
, t.[SECOND_LEVEL_ITEM!2!name], t.[SECOND_LEVEL_ITEM!2!id]
, t.[THIRD_LEVEL_ITEM!3!name], t.[THIRD_LEVEL_ITEM!3!id]
, t.[FOURTH_LEVEL_ITEM!4!name], t.[FOURTH_LEVEL_ITEM!4!id]
FROM #TABLE_XML1
OUTER APPLY (
SELECT 1 AS Tag, NULL AS PARENT
, TOP_LEVEL_ITEM AS [TOP_LEVEL_ITEM!1!name], TOP_LEVEL_ID AS [TOP_LEVEL_ITEM!1!id]
, NULL AS [SECOND_LEVEL_ITEM!2!name], NULL AS [SECOND_LEVEL_ITEM!2!id]
, NULL AS [THIRD_LEVEL_ITEM!3!name], NULL AS [THIRD_LEVEL_ITEM!3!id]
, NULL AS [FOURTH_LEVEL_ITEM!4!name], NULL AS [FOURTH_LEVEL_ITEM!4!id]
UNION
SELECT 2, 1
, NULL, TOP_LEVEL_ID
, SECOND_LEVEL_ITEM, SECOND_LEVEL_ID
, NULL, NULL
, NULL, NULL
UNION
SELECT 3, 2
, NULL, TOP_LEVEL_ID
, NULL, SECOND_LEVEL_ID
, THIRD_LEVEL_ITEM, THIRD_LEVEL_ID
, NULL, NULL
WHERE THIRD_LEVEL_ID IS NOT NULL
UNION
SELECT 4, 3
, NULL, TOP_LEVEL_ID
, NULL, SECOND_LEVEL_ID
, NULL, THIRD_LEVEL_ID
, FOURTH_LEVEL_ITEM, FOURTH_LEVEL_ID
WHERE FOURTH_LEVEL_ID IS NOT NULL
) AS t
ORDER BY t.[TOP_LEVEL_ITEM!1!id], t.[SECOND_LEVEL_ITEM!2!id], t.[THIRD_LEVEL_ITEM!3!id], t.[FOURTH_LEVEL_ITEM!4!id]
FOR XML EXPLICIT

Drew


J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
Post #1425704
Posted Monday, March 04, 2013 3:37 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, April 02, 2014 6:16 AM
Points: 151, Visits: 282
Many Thanks Drew,

This works really well. The table was just a poor example of a larger table I was working on. Sorry about the inconsistencies. One question for you, isn't XML explicit deprecated for future versions. Is this something I should be concerned about?

Many Thanks,

Oliver
Post #1426158
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse