Tek-Tips is the largest IT community on the Internet today!

Members share and learn making Tek-Tips Forums the best source of peer-reviewed technical information on the Internet!

  • Congratulations SkipVought on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

JOIN query help needed 2

Status
Not open for further replies.

RosieGp

Programmer
Jun 23, 2009
83
0
0
US
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.
 
Since you don't want to see these 2 same records, just one of them:

Code:
ID	Dealer	Brand	ProductNumber	Rating
[highlight #FCE94F]1	Sam	Chevy	C_10, C_11	5, 4.5,
1	Sam	Chevy	C_10, C_11	5, 4.5,
[/highlight]3	Darcy	Fiat	F_12		2
4	Donny	Chysler	CH_3		3

Wouldn't:[tt] Select [blue]DISTINCT[/blue] S.ID, S.Dealer, P.Brand, R.ProductNumber, ...[/tt] do the trick?


Have fun.

---- Andy

There is a great need for a sarcasm font.
 
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
 
Thanks Andy. i guess i was too tired and not thinking straight. thanks again.
 
Status
Not open for further replies.

Part and Inventory Search

Sponsor

Back
Top