INTELLIGENT WORK FORUMS
FOR COMPUTER PROFESSIONALS

Log In

Come Join Us!

Are you a
Computer / IT professional?
Join Tek-Tips Forums!
  • Talk With Other Members
  • Be Notified Of Responses
    To Your Posts
  • Keyword Search
  • One-Click Access To Your
    Favorite Forums
  • Automated Signatures
    On Your Posts
  • Best Of All, It's Free!

*Tek-Tips's functionality depends on members receiving e-mail. By joining you are opting in to receive e-mail.

Posting Guidelines

Promoting, selling, recruiting, coursework and thesis posting is forbidden.

Jobs

JOIN query help needed

JOIN query help needed

(OP)
Hello - i have following 3 tables:
tbl_Rating

CODE

ID	ProductNumber	Rating
1	C_10, C_11	5
1	C_10, C_11	4.5
3	F_12		2
4	CH_3		3 
tbl_Sold

CODE

ID	ProductName	Dealer	ProductSOld
1	Chevy Cruise	Sam	2
3	Fiat Compact	Darcy	1
4	Chysler Van	Donny	1 
tbl_Product

CODE

ID	Brand
1	Chevy
2	GM
3	Fiat
4	Chysler 

SO far i have the follwoing query:

CODE

Select S.ID, S.Dealer, P.Brand, R.ProductNumber, 
       ( SELECT R.Rating + ', '
          FROM tbl_Rating R
          WHERE R.ID = S.ID
          ORDER BY R.Rating
          FOR XML PATH('') ) AS Rating2
FROM tbl_Sold S
    LEFT JOIN tbl_Product P ON P.ID = S.ID
    LEFT JOIN tbl_Rating R ON R.ID = S.ID
WHERE S.ProductSOld IS NOT NULL
GROUP BY S.ID, S.Dealer, P.Brand, R.ProductNumber, R.Rating
ORDER BY S.ID 

CODE

ID	Dealer	Brand	ProductNumber	Rating
1	Sam	Chevy	C_10, C_11	5, 4.5,
1	Sam	Chevy	C_10, C_11	5, 4.5,
3	Darcy	Fiat	F_12		2
4	Donny	Chysler	CH_3		3 

I need to query modified to show the following results:

CODE

ID	Dealer	Brand	ProductNumber	Rating
1	Sam	Chevy	C_10, C_11	5, 4.5
3	Darcy	Fiat	F_12		2
4	Donny	Chysler	CH_3		3 

Any help is appreciated.
Thanks.

RE: JOIN query help needed

Since you don't want to see these 2 same records, just one of them:

CODE

ID	Dealer	Brand	ProductNumber	Rating
1	Sam	Chevy	C_10, C_11	5, 4.5,
1	Sam	Chevy	C_10, C_11	5, 4.5,
3	Darcy	Fiat	F_12		2
4	Donny	Chysler	CH_3		3 

Wouldn't: Select DISTINCT S.ID, S.Dealer, P.Brand, R.ProductNumber, ... do the trick?

Have fun.

---- Andy

There is a great need for a sarcasm font.

RE: JOIN query help needed

One common mistake that programmers make when writing this type of query is to try to do too much at once. I'm specifically referring to the part of creating a comma list of ratings. In my opinion, it's best to do this sort of thing with the least number of tables possible.

For example, to get just the ratings part, you can do this:

CODE

Select P.ID, 
       P.ProductNumber,
       LTrim(( SELECT ' ' + R.Rating + ','
	       FROM tbl_Rating R
               WHERE R.ID = P.ID
               ORDER BY R.Rating
               FOR XML PATH('') )) AS Rating2
FROM   tbl_Rating P
GROUP BY P.ID, P.ProductNumber 

Basically, you really only need 1 table to get the comma list of ratings, so why use more tables when you don't need to.

Obviously, you need to combine this with other tables to get your desired output, so now that you have this query that works properly, you can use it as a common table expression to get your final results, like this:

CODE

;With Ratings As 
(
  Select P.ID, 
         P.ProductNumber,
         LTrim(( SELECT ' ' + R.Rating + ','
                 FROM tbl_Rating R
                 WHERE R.ID = P.ID
                 ORDER BY R.Rating
                 FOR XML PATH('') )) AS Rating2
  FROM    tbl_Rating P
  GROUP BY P.ID, P.ProductNumber
)
Select  S.ID, 
        S.Dealer, 
        P.Brand, 
        Ratings.ProductNumber, 		
        Case When Right(Rating2, 1) = ','
             Then Left(Rating2, Len(Rating2)-1)
             Else Rating2
             End As Rating
FROM    tbl_Sold S
        LEFT JOIN tbl_Product P ON P.ID = S.ID
        LEFT JOIN Ratings On S.ID = Ratings.Id
WHERE   S.ProductSOld IS NOT NULL
ORDER BY S.ID 

-George
Microsoft SQL Server MVP
My Blogs
SQLCop
twitter
"The great things about standards is that there are so many to choose from." - Fortune Cookie Wisdom

RE: JOIN query help needed

(OP)
Thanks Andy. i guess i was too tired and not thinking straight. thanks again.

Red Flag This Post

Please let us know here why this post is inappropriate. Reasons such as off-topic, duplicates, flames, illegal, vulgar, or students posting their homework.

Red Flag Submitted

Thank you for helping keep Tek-Tips Forums free from inappropriate posts.
The Tek-Tips staff will check this out and take appropriate action.

Reply To This Thread

Posting in the Tek-Tips forums is a member-only feature.

Click Here to join Tek-Tips and talk with other members!

Resources

Close Box

Join Tek-Tips® Today!

Join your peers on the Internet's largest technical computer professional community.
It's easy to join and it's free.

Here's Why Members Love Tek-Tips Forums:

Register now while it's still free!

Already a member? Close this window and log in.

Join Us             Close