Tags

, , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , ,


SQL PUZZLE | Fetch ALL attributes & values dynamically from XML? | Advanced SQL

In this you have to go through the XML and get all the attributes names and values without providing the node names. Please see the sample input and expected output.

Sample-1

--

<?xml version="1.0"?>
<Gate specVersion="3.20">
	<User UserId="PawanWithSQLServer">
	<MyMethods>
		<Method type="Cell">3264532</Method>
		<Method type="Email">Pawan@MSBISKills.com</Method>
		<Method type="WebSite">MSBISKills.com</Method>
		<Method type="Fax"></Method>		
	</MyMethods>
	</User>
</Gate>

--

Expected output-1

Nm Vals
specVersion 3.20
UserId PawanWithSQLServer
type Cell
type Email
type WebSite
type Fax

Script – DDL and INSERT sample data

--

DECLARE @XML AS XML = '<?xml version="1.0"?>
<Gate specVersion="3.20">
	<User UserId="PawanWithSQLServer">
	<MyMethods>
		<Method type="Cell">3264532</Method>
		<Method type="Email">Pawan@MSBISKills.com</Method>
		<Method type="WebSite">MSBISKills.com</Method>
		<Method type="Fax"></Method>		
	</MyMethods>
	</User>
</Gate>'

--

SOLUTION – 1

--

DECLARE @XML AS XML = '<?xml version="1.0"?>
<Gate specVersion="3.20">
	<User UserId="PawanWithSQLServer">
	<MyMethods>
		<Method type="Cell">3264532</Method>
		<Method type="Email">Pawan@MSBISKills.com</Method>
		<Method type="WebSite">MSBISKills.com</Method>
		<Method type="Fax"></Method>		
	</MyMethods>
	</User>
</Gate>'

DECLARE @m TABLE  (Xmls XML)
INSERT INTO @m SELECT @XML
SELECT
		p.value('local-name(.)', 'VARCHAR(100)') As Nm,
		p.value('.','NVARCHAR(MAX)') As Vals		
FROM @XML.nodes('//node()//@*') AS u(p)

--

Output – 1

--

Nm                       Vals
------------------------ -------------------------
specVersion              3.20
UserId                   PawanWithSQLServer
type                     Cell
type                     Email
type                     WebSite
type                     Fax

(6 rows affected)

--

Enjoy 🙂

Please add comment(s) if you have one or multiple solutions in mind. Thank You.

Pawan Khowal

Pawan is a SQL Server Developer. If you need any help in writing code/puzzle or training please email at – pawankkmr”AT”gmail.com. Meanwhile please go throgh the top pages from his blog.

Page Detail URL
☛ SQL Advance Puzzles https://msbiskills.com/tsql-puzzles-asked-in-interview-over-the-years/
☛ SQL Tricky Queries https://msbiskills.com/sql-puzzles-finding-outputs/
☛ SQL Server Perfomance tuning Articles https://msbiskills.com/sql-performance-tuning/
☛ SQL Server Articles https://msbiskills.com/t-sql/
☛ SQL Interview Questions & Answers https://msbiskills.com/sql-server-interview-questions/

My SQL Groups on Facebook:

1. If you like this post, you may want to join my SQL SERVER Interview Puzzles/Interview Questions on Facebook: https://www.facebook.com/groups/1430882120556342/

2. If you like this post, you may want to join my SQL Server Puzzles on Facebook:
https://www.facebook.com/groups/206594023090781/

My SQL Page on Facebook:

2. For all the updates you may follow my page -> https://www.facebook.com/MSBISkillscom-1602779883299222/

Enjoy !!! Keep Learning

Http://MsbiSkills.com