Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Noob xquery problem Expand / Collapse
Author
Message
Posted Sunday, April 6, 2014 10:05 PM


Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Monday, May 26, 2014 7:27 AM
Points: 71, Visits: 193
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!
Post #1558899
Posted Sunday, April 6, 2014 10:51 PM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Today @ 9:26 PM
Points: 1,294, Visits: 3,717
The nodes() method of the xml datatype makes this straight forward.


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
Post #1558906
Posted Monday, April 7, 2014 6:29 AM This worked for the OP Answer marked as solution
Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Saturday, June 7, 2014 4:22 AM
Points: 565, Visits: 8,703

[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, MCITP
Post #1559030
Posted Monday, April 7, 2014 6:21 PM


Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Monday, May 26, 2014 7:27 AM
Points: 71, Visits: 193
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
Post #1559315
Posted Monday, April 7, 2014 9:50 PM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Today @ 9:26 PM
Points: 1,294, Visits: 3,717
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
Post #1559345
Posted Tuesday, April 8, 2014 4:44 AM
Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Saturday, June 7, 2014 4:22 AM
Points: 565, Visits: 8,703
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, MCITP
Post #1559424
Posted Tuesday, April 8, 2014 4:55 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Today @ 9:26 PM
Points: 1,294, Visits: 3,717
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.
Post #1559431
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse