January 3, 2018 at 7:51 am
Hi,
I have below XML and i need to fetch the data for First set of token tag
<tokens>
<token>
<typeid>1</typeid>
<p1>0.15</p1>
</token>
<token>
<typeid>1</typeid>
<op>+</op>
<p1>2.568</p1>
</token>
</tokens>
Output i need for first token set as highlighted above Typeid as 1 and p1 as 0.15 i dont want to read/parse the entire xml only first set of tag <token> here in this case. using tsql. Please help
Thanks
Sam
January 3, 2018 at 8:29 am
This what you're looking for?
DECLARE @XML xml;
SET @XML =
'<tokens>
<token>
<typeid>1</typeid>
<p1>0.15</p1>
</token>
<token>
<typeid>1</typeid>
<op>+</op>
<p1>2.568</p1>
</token>
</tokens>';
SELECT X.T.value('(token/typeid/text())[1]','int') AS typedid,
X.T.value('(token/p1/text())[1]','decimal(6,3)') AS p1
FROM @XML.nodes('/tokens') X(T);
Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does.
Larnu.uk
January 3, 2018 at 8:44 am
Since you're only looking for ONE row, there is no reason to use the relatively expensive .nodes() function.
SELECT @XML.value('(/tokens/token/typeid/text())[1]', 'int') AS typeidid,
@XML.value('(/tokens/token/p1/text())[1]', 'decimal(6,3)') AS p1id
Drew
J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
January 3, 2018 at 8:54 am
drew.allen - Wednesday, January 3, 2018 8:44 AMSince you're only looking for ONE row, there is no reason to use the relatively expensive .nodes() function.
SELECT @XML.value('(/tokens/token/typeid/text())[1]', 'int') AS typeidid,
@XML.value('(/tokens/token/p1/text())[1]', 'decimal(6,3)') AS p1idDrew
Good point Drew, the nodes() function will parse and then reconstruct the xml, quite costly!
January 3, 2018 at 9:14 am
Eirikur Eiriksson - Wednesday, January 3, 2018 8:54 AMdrew.allen - Wednesday, January 3, 2018 8:44 AMSince you're only looking for ONE row, there is no reason to use the relatively expensive .nodes() function.
SELECT @XML.value('(/tokens/token/typeid/text())[1]', 'int') AS typeidid,
@XML.value('(/tokens/token/p1/text())[1]', 'decimal(6,3)') AS p1idDrew
Good point Drew, the nodes() function will parse and then reconstruct the xml, quite costly!
Hadn't considered that, in all honestly. Thanks Drew.
Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does.
Larnu.uk
January 3, 2018 at 10:25 am
Thom A - Wednesday, January 3, 2018 9:14 AMEirikur Eiriksson - Wednesday, January 3, 2018 8:54 AMdrew.allen - Wednesday, January 3, 2018 8:44 AMSince you're only looking for ONE row, there is no reason to use the relatively expensive .nodes() function.
SELECT @XML.value('(/tokens/token/typeid/text())[1]', 'int') AS typeidid,
@XML.value('(/tokens/token/p1/text())[1]', 'decimal(6,3)') AS p1idDrew
Good point Drew, the nodes() function will parse and then reconstruct the xml, quite costly!
Hadn't considered that, in all honestly. Thanks Drew.
Thanks for Quick help..
Viewing 6 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply
This website stores cookies on your computer.
These cookies are used to improve your website experience and provide more personalized services to you, both on this website and through other media.
To find out more about the cookies we use, see our Privacy Policy