Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Noob xquery problem


Noob xquery problem

Author
Message
rho_pooka
rho_pooka
Valued Member
Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)

Group: General Forum Members
Points: 73 Visits: 205
Hi all, I'm still having a hard time writing out xquery statements. I have a better grasp of querying element centric xml, but now that I've turned my attention to attribute centric I'm confused (again). Here's currently what I'm working with:

 DECLARE @X XML
SET @X = '<root>
<production.Categories categoryid="1" categoryname="Beverages" description="Soft drinks, coffees, teas, beers, and ales" />
<production.Categories categoryid="2" categoryname="Condiments" description="Sweet and savory sauces, relishes, spreads, and seasonings" />
<production.Categories categoryid="3" categoryname="Confections" description="Desserts, candies, and sweet breads" />
<production.Categories categoryid="4" categoryname="Dairy Products" description="Cheeses" />
<production.Categories categoryid="5" categoryname="Grains/Cereals" description="Breads, crackers, pasta, and cereal" />
<production.Categories categoryid="6" categoryname="Meat/Poultry" description="Prepared meats" />
<production.Categories categoryid="7" categoryname="Produce" description="Dried fruit and bean curd" />
<production.Categories categoryid="8" categoryname="Seafood" description="Seaweed and fish" />
<production.Categories categoryid="9" categoryname="Beer" description="Budweiser" />
<production.Categories categoryid="10" categoryname="Liquor" description="Captain Morgan" />
</root>'



So just to start, how can I see categoryid 9's categoryname, and description? Is it possible? I would assume that the code would look something like this:
SELECT @x.query('data(//root[@category=9])');

but that is giving me zero output. Any helps in pointing me in the right direction would be appreciated, I'm feeling stumped!
Eirikur Eiriksson
Eirikur Eiriksson
SSCertifiable
SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)

Group: General Forum Members
Points: 6837 Visits: 17773
The nodes() method of the xml datatype makes this straight forward.
Cool

DECLARE @X XML
SET @X = '<root>
<production.Categories categoryid="1" categoryname="Beverages" description="Soft drinks, coffees, teas, beers, and ales" />
<production.Categories categoryid="2" categoryname="Condiments" description="Sweet and savory sauces, relishes, spreads, and seasonings" />
<production.Categories categoryid="3" categoryname="Confections" description="Desserts, candies, and sweet breads" />
<production.Categories categoryid="4" categoryname="Dairy Products" description="Cheeses" />
<production.Categories categoryid="5" categoryname="Grains/Cereals" description="Breads, crackers, pasta, and cereal" />
<production.Categories categoryid="6" categoryname="Meat/Poultry" description="Prepared meats" />
<production.Categories categoryid="7" categoryname="Produce" description="Dried fruit and bean curd" />
<production.Categories categoryid="8" categoryname="Seafood" description="Seaweed and fish" />
<production.Categories categoryid="9" categoryname="Beer" description="Budweiser" />
<production.Categories categoryid="10" categoryname="Liquor" description="Captain Morgan" />
</root>'

SELECT
RO.CT.value('@categoryid','INT') AS categoryid
,RO.CT.value('@categoryname','NVARCHAR(250)') AS categoryname
,RO.CT.value('@description','NVARCHAR(2048)') AS description

FROM @X.nodes('root/production.Categories') AS RO(CT);



Output
categoryid  categoryname         description
----------- -------------------- ------------------------------------------------------------
1 Beverages Soft drinks, coffees, teas, beers, and ales
2 Condiments Sweet and savory sauces, relishes, spreads, and seasonings
3 Confections Desserts, candies, and sweet breads
4 Dairy Products Cheeses
5 Grains/Cereals Breads, crackers, pasta, and cereal
6 Meat/Poultry Prepared meats
7 Produce Dried fruit and bean curd
8 Seafood Seaweed and fish
9 Beer Budweiser
10 Liquor Captain Morgan

Russel Loski
Russel Loski
Mr or Mrs. 500
Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)

Group: General Forum Members
Points: 593 Visits: 8883
[code="sql"]
SET @X = '<root>
<production.Categories categoryid="1" categoryname="Beverages" description="Soft drinks, coffees, teas, beers, and ales" />
<production.Categories categoryid="2" categoryname="Condiments" description="Sweet and savory sauces, relishes, spreads, and seasonings" />
<production.Categories categoryid="3" categoryname="Confections" description="Desserts, candies, and sweet breads" />
<production.Categories categoryid="4" categoryname="Dairy Products" description="Cheeses" />
<production.Categories categoryid="5" categoryname="Grains/Cereals" description="Breads, crackers, pasta, and cereal" />
<production.Categories categoryid="6" categoryname="Meat/Poultry" description="Prepared meats" />
<production.Categories categoryid="7" categoryname="Produce" description="Dried fruit and bean curd" />
<production.Categories categoryid="8" categoryname="Seafood" description="Seaweed and fish" />
<production.Categories categoryid="9" categoryname="Beer" description="Budweiser" />
<production.Categories categoryid="10" categoryname="Liquor" description="Captain Morgan" />
</root>'

SELECT
@x.value('(root/production.Categories[@categoryid="9"]/@categoryid)[1]','INT') AS categoryid
,@x.value('(root/production.Categories[@categoryid="9"]/@categoryname')[1],'NVARCHAR(250)') AS categoryname
,@.value('(root/production.Categories[@categoryid="9"]/@description)[1]','NVARCHAR(2048)') AS description

Russel Loski, MCSE Business Intelligence, Data Platform
rho_pooka
rho_pooka
Valued Member
Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)

Group: General Forum Members
Points: 73 Visits: 205
Thanks a ton for the help! Can the answer look different if you wanted to use node navigation? I think that's what I was trying to do the first time, and I really confused myself.

Thanks again,
Ben
Eirikur Eiriksson
Eirikur Eiriksson
SSCertifiable
SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)

Group: General Forum Members
Points: 6837 Visits: 17773
rho_pooka (4/7/2014)
Thanks a ton for the help! Can the answer look different if you wanted to use node navigation? I think that's what I was trying to do the first time, and I really confused myself.

Thanks again,
Ben


DECLARE @X XML
SET @X = '<root>
<production.Categories categoryid="1" categoryname="Beverages" description="Soft drinks, coffees, teas, beers, and ales" />
<production.Categories categoryid="2" categoryname="Condiments" description="Sweet and savory sauces, relishes, spreads, and seasonings" />
<production.Categories categoryid="3" categoryname="Confections" description="Desserts, candies, and sweet breads" />
<production.Categories categoryid="4" categoryname="Dairy Products" description="Cheeses" />
<production.Categories categoryid="5" categoryname="Grains/Cereals" description="Breads, crackers, pasta, and cereal" />
<production.Categories categoryid="6" categoryname="Meat/Poultry" description="Prepared meats" />
<production.Categories categoryid="7" categoryname="Produce" description="Dried fruit and bean curd" />
<production.Categories categoryid="8" categoryname="Seafood" description="Seaweed and fish" />
<production.Categories categoryid="9" categoryname="Beer" description="Budweiser" />
<production.Categories categoryid="10" categoryname="Liquor" description="Captain Morgan" />
</root>'

SELECT
RO.CT.value('@categoryid','INT') AS categoryid
,RO.CT.value('@categoryname','NVARCHAR(250)') AS categoryname
,RO.CT.value('@description','NVARCHAR(2048)') AS description

FROM @X.nodes('root/production.Categories') AS RO(CT)
WHERE RO.CT.value('@categoryid','INT') = 9;



Use the "WHERE" Luke Cool
Russel Loski
Russel Loski
Mr or Mrs. 500
Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)Mr or Mrs. 500 (593 reputation)

Group: General Forum Members
Points: 593 Visits: 8883
You can use the where or put the query into your XQuery (I don't know which is more efficient):

DECLARE @X XML;
DECLARE @CategoryID int = 9;

SET @X = '<root>
<production.Categories categoryid="1" categoryname="Beverages"
description="Soft drinks, coffees, teas, beers, and ales" />
<production.Categories categoryid="2" categoryname="Condiments"
description="Sweet and savory sauces, relishes, spreads, and seasonings" />
<production.Categories categoryid="3" categoryname="Confections"
description="Desserts, candies, and sweet breads" />
<production.Categories categoryid="4" categoryname="Dairy Products"
description="Cheeses" />
<production.Categories categoryid="5" categoryname="Grains/Cereals"
description="Breads, crackers, pasta, and cereal" />
<production.Categories categoryid="6" categoryname="Meat/Poultry"
description="Prepared meats" />
<production.Categories categoryid="7" categoryname="Produce"
description="Dried fruit and bean curd" />
<production.Categories categoryid="8" categoryname="Seafood"
description="Seaweed and fish" />
<production.Categories categoryid="9" categoryname="Beer"
description="Budweiser" />
<production.Categories categoryid="10" categoryname="Liquor"
description="Captain Morgan" />
</root>'
SELECT
RO.CT.value('@categoryid','INT') AS categoryid
,RO.CT.value('@categoryname','NVARCHAR(250)') AS categoryname
,RO.CT.value('@description','NVARCHAR(2048)') AS description
FROM @X.nodes
('root/production.Categories[@categoryid=sql:variable("@CategoryID")]')
AS RO(CT)



Russel Loski, MCSE Business Intelligence, Data Platform
Eirikur Eiriksson
Eirikur Eiriksson
SSCertifiable
SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)

Group: General Forum Members
Points: 6837 Visits: 17773
Russel Loski (4/8/2014)
You can use the where or put the query into your XQuery (I don't know which is more efficient):


Not much of a difference for an untyped xml, typed xml is more likely to benefit from it.
Cool
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search