May 16, 2017 at 11:48 am
I've searched the web to no avail. So PLEASE help out!
I have a table:
CREATE TABLE [Course].[Navigation](
[NavigationId] [int] IDENTITY(1,1) NOT NULL,
ParentID int,
ChildID int,
[Type] [varchar](100) NULL,
[Label] [int] NULL,
[Id] [varchar](100) NULL )
Which represents a navigational chart for a course.
The XML that I'm trying to load is:
'<navigation>
<content label="Introduction">
<content label="Intro" id="000286_1001"/>
</content>
<content label="Premature Atrial Contractions">
<content label="Description" id="000286_1002"/>
<content label="ECG Features" id="000286_1003"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1004"/>
</content>
<content label="Wandering">
<content label="Description" id="000286_1005"/>
<content label="ECG Features" id="000286_1006"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1007"/>
</content>
<content label="Ectopic Atrial Rhythm">
<content label="Description" id="000286_1008"/>
<content label="ECG Features" id="000286_1009"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1010"/>
</content>
<content label="Supraventricular Tachycardia">
<content label="SVT" id="000286_1011"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1012"/>
<content label="Multifocal Atrial Tachycardia">
<content label="Description" id="000286_1013"/>
<content label="ECG Features" id="000286_1014"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1015"/>
</content>
<content label="Ectopic Atrial Tachycardia">
<content label="Description" id="000286_1016"/>
<content label="ECG Features" id="000286_1017"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1018"/>
</content>
<content label="Ectopic Atrial Tachycardia with Block">
<content label="Description" id="000286_1019"/>
</content>
<content label="Atrial Flutter">
<content label="Description" id="000286_1020"/>
<content label="ECG Features" id="000286_1021"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1022"/>
<content label="Treatment" id="000286_1023"/>
</content>
<content label="Atrial Fibrillation">
<content label="Description" id="000286_1024"/>
<content label="ECG Features" id="000286_1025"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1026"/>
<content label="Signs" id="000286_1027"/>
<content label="Treatment" id="000286_1028"/>
</content>
<content label="AVRT">
<content label="Description" id="000286_1029"/>
<content label="Pathophysiology" id="000286_1030"/>
<content label="ECG Features" id="000286_1031"/>
<content label="Etiology" id="000286_1032"/>
</content>
<content label="AVNRT">
<content label="Description" id="000286_1033"/>
<content label="ECG Features" id="000286_1034"/>
<content label="Etiology" id="000286_1035"/>
</content>
<content label="Treatment" id="000286_1036"/>
</content>
<content label="Review">
<content label="Quick Quiz" id="000286_1037"/>
</content>
<content label="Conclusion">
<content label="Summary" id="000286_1038"/>
</content>
</navigation> '
May 16, 2017 at 3:20 pm
Patrick - just to be extra clear - can you model up/dummy up what it is you're expecting to get back? Are you essentially trying to just return XML snippets as XML based on the bigger document?
----------------------------------------------------------------------------------
Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?
May 16, 2017 at 3:37 pm
I cannot identify what you are looking for, but perhaps this will start you off along the right track.
DECLARE @data XML = N'<navigation>
<content label="Introduction">
<content label="Intro" id="000286_1001"/>
</content>
<content label="Premature Atrial Contractions">
<content label="Description" id="000286_1002"/>
<content label="ECG Features" id="000286_1003"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1004"/>
</content>
<content label="Wandering">
<content label="Description" id="000286_1005"/>
<content label="ECG Features" id="000286_1006"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1007"/>
</content>
<content label="Ectopic Atrial Rhythm">
<content label="Description" id="000286_1008"/>
<content label="ECG Features" id="000286_1009"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1010"/>
<content label="Supraventricular Tachycardia">
<content label="SVT" id="000286_1011"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1012"/>
</content>
<content label="Multifocal Atrial Tachycardia">
<content label="Description" id="000286_1013"/>
<content label="ECG Features" id="000286_1014"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1015"/>
</content>
<content label="Ectopic Atrial Tachycardia">
<content label="Description" id="000286_1016"/>
<content label="ECG Features" id="000286_1017"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1018"/>
</content>
<content label="Ectopic Atrial Tachycardia with Block">
<content label="Description" id="000286_1019"/>
</content>
<content label="Atrial Flutter">
<content label="Description" id="000286_1020"/>
<content label="ECG Features" id="000286_1021"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1022"/>
<content label="Treatment" id="000286_1023"/>
</content>
<content label="Atrial Fibrillation">
<content label="Description" id="000286_1024"/>
<content label="ECG Features" id="000286_1025"/>
<content label="Etiology/Symptoms/Treatment" id="000286_1026"/>
<content label="Signs" id="000286_1027"/>
<content label="Treatment" id="000286_1028"/>
</content>
<content label="AVRT">
<content label="Description" id="000286_1029"/>
<content label="Pathophysiology" id="000286_1030"/>
<content label="ECG Features" id="000286_1031"/>
<content label="Etiology" id="000286_1032"/>
</content>
<content label="AVNRT">
<content label="Description" id="000286_1033"/>
<content label="ECG Features" id="000286_1034"/>
<content label="Etiology" id="000286_1035"/>
</content>
<content label="Treatment" id="000286_1036"/>
</content>
<content label="Review">
<content label="Quick Quiz" id="000286_1037"/>
</content>
<content label="Conclusion">
<content label="Summary" id="000286_1038"/>
</content>
</navigation> ';
SELECT
NavigationId = ROW_NUMBER() OVER (ORDER BY ISNULL(C.c.value('@id', 'VARCHAR(50)'), '999999_999')
, ISNULL(G.r.value('@id', 'VARCHAR(50)'), '999999_999'))
, [Type] = T.l.value('@label', 'VARCHAR(100)')
, Parent_label = C.c.value('@label', 'VARCHAR(100)')
, Parent_id = C.c.value('@id', 'VARCHAR(50)')
, Child_label = G.r.value('@label', 'VARCHAR(100)')
, Child_id = G.r.value('@id', 'VARCHAR(50)')
FROM @data.nodes('navigation/content') AS T(l)
CROSS APPLY T.l.nodes('content') AS C(c)
OUTER APPLY C.c.nodes('content') AS G(r);
May 16, 2017 at 3:50 pm
This might get you started, but without knowing your end game, I have no idea what to aim for:SELECT X.N.value('@label','nvarchar(50)') AS [Type],
C.T.value('@label','nvarchar(50)') AS Label,
C.T.value('@id','nvarchar(50)') AS id
FROM @XML.nodes('/navigation/content') X(N)
CROSS APPLY X.N.nodes('./content') C(T);
Edit: Des was way ahead of me while I had to (once again) Google how to use XQuery 😛
Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does.
Larnu.uk
May 17, 2017 at 6:00 am
With no reflection on the OP because he's the poor consumer of this data and not the perpetrator... you just have to wonder what the heck is on people's minds when they build such XML. It's certainly meant to be hierarchical but they used the XML like a typewriter instead of using the abilities of XML. A simple numbered list TSV would have been more effective in just about every manner.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply