SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 SQL Server 2012 Forums
 Transact-SQL (2012)
 XML column data extract(T-SQL) - Need help
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

manjunathvenkatesh
Starting Member

India
2 Posts

Posted - 08/21/2014 :  12:41:10  Show Profile  Reply with Quote
I am trying to extract the below highlighted data from an XML column value (column - Details) as shown in the example below,


Work Table structure (T SQL)
Identity Details
1 <ab Line="32" section="Furniture" />
2 <ab Line="37" section="Household" />
3 <ab Line="38" section="Electronics" />

Result should be
Id Details
32 Furniture
37 Household
38 Electronics

I have tried ,

select
X.N.value('Line[1]', 'int') as Id
,X.N.value('section[1]', 'varchar(5)') as Details
from Work as T
cross apply T.Details.nodes('/ab') as X(N)

select EventParameter.value('(ab/Line)[1]','int') as Id
,EventParameter.value('(ab/section)[1]','varchar(10)') as Details
from Work


SELECT
R.ref.value ('@Line', 'int') as Id
FROM Work
CROSS APPLY EventParameter.nodes ('/ab/Line') R(ref)

All of these above queries are returning NULL in result set.


Could you please advise me on how to extract column value from this XML column.


SwePeso
Patron Saint of Lost Yaks

Sweden
30242 Posts

Posted - 08/21/2014 :  16:27:50  Show Profile  Visit SwePeso's Homepage  Reply with Quote
DECLARE	@Sample TABLE
	(
		RowID INT PRIMARY KEY CLUSTERED,
		Data XML NOT NULL
	);

INSERT	@Sample
	(
		RowID,
		Data
	)
VALUES	(1, '<ab Line="32" section="Furniture" />'),
	(2, '<ab Line="37" section="Household" />'),
	(3, '<ab Line="38" section="Electronics" />');

-- SwePeso
SELECT		ab.n.value('(@Line)', 'INT') AS Line,
		ab.n.value('(@section)', 'VARCHAR(100)') AS Section
FROM		@Sample AS s
CROSS APPLY	s.Data.nodes('(/ab)') AS ab(n);



Microsoft SQL Server MVP, MCT, MCSE, MCSA, MCP, MCITP, MCTS, MCDBA
Go to Top of Page

manjunathvenkatesh
Starting Member

India
2 Posts

Posted - 08/22/2014 :  03:48:02  Show Profile  Reply with Quote
Thank You.
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.03 seconds. Powered By: Snitz Forums 2000