Read XML column attributes in to two columns DimType and Dimvalue from the below example also retrieve the data matching values[DimTypes (WIDTH or Height)].
‘<dimensions>
<dimension name=”width” value=”12.77″/>
<dimension name=”height” value=”0.14″/>
<dimension name=”depth” value=”12.92″/>
</dimenstions>’
Download SQL :- https://gallery.technet.microsoft.com/SQL-Querying-XML-f700bbb0
SQL:-
DECLARE @xml XML SELECT @xml = '<dimensions> <dimension name="height" value="0.14" /> <dimension name="width" value="12.77"/> </dimensions>' SELECT x.v.value('@name[1]', 'VARCHAR(100)') AS dimtype , x.v.value('@value[1]', 'VARCHAR(100)') AS dimvalue FROM @xml.nodes('/dimensions/dimension') x(v)
create table #demo (field1 xml) insert into #demo (field1) values ('<dimensions> <dimension name="height" value="0.14" /> <dimension name="width" value="12.77"/> </dimensions>') SELECT x.v.value('@name[1]', 'VARCHAR(100)') AS dimtype , x.v.value('@value[1]', 'VARCHAR(100)') AS dimvalue from #demo cross apply field1.nodes('/dimensions/dimension') x(v)
Select data for DimType “height and Width”
DECLARE @xml XML SELECT @xml = '<dimensions> <dimension name="height" value="0.14" /> <dimension name="width" value="12.77"/> <dimension name="depth" value="12.92"/> </dimensions>' SELECT x.v.value('@name[1]', 'VARCHAR(100)') AS dimtype , x.v.value('@value[1]', 'VARCHAR(100)') AS dimvalue FROM @xml.nodes('/dimensions/dimension[@name = "height" or @name = "width"]') x(v)
Using Temp table and Join –
create table #demo (field1 xml) insert into #demo (field1) values ('<dimensions> <dimension name="height" value="0.14" /> <dimension name="width" value="12.77"/> </dimensions>') SELECT x.v.value('@name[1]', 'VARCHAR(100)') AS dimtype , x.v.value('@value[1]', 'VARCHAR(100)') AS dimvalue from #demo cross apply field1.nodes('/dimensions/dimension[@name = "height" or @name = "width"]') x(v)
Using SQL Where Clause to fetch dimension type data ‘HEIGHT’ or ‘WIDTH’
CREATE TABLE #demo (field1 xml) INSERT INTO #demo (field1) values ('<dimensions> <dimension name="height" value="0.14" /> <dimension name="width" value="12.77"/> <dimension name="depth" value="12.92"/> </dimensions>') select * from #demo select dimtype, dimvalue FROM ( SELECT x.v.value('@name[1]', 'VARCHAR(100)') AS dimtype , x.v.value('@value[1]', 'VARCHAR(100)') AS dimvalue from #demo cross apply field1.nodes('/dimensions/dimension') x(v) )T where T.dimtype in('height','width')