Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 Including ID column when using GROUP BY

Author  Topic 

figmo
Starting Member

18 Posts

Posted - 2013-02-27 : 12:28:51
I know this should be simple but GROUP BY just kicks my butt every time I have to use it. Given this type of table:

ID int
Artist varchar
Title varchar
Quality int

ID is a unique primary key. The data contained has multiple rows with the same Artist and Title name. Quality may or may not be the same. So you might have data like this...

10, 'Artist1', 'Title1', 3
11, 'Artist1', 'Title1', 2
12, 'Artist1', 'Title1', 1
13, 'Artist2', 'Title2', 3
14, 'Artist2', 'Title2', 2
15, 'Artist2', 'Title2', 1
16, 'Artist2', 'Title2', 2
17, 'Artist2', 'Title2', 1

I want to show a unique list of ID, Artist, Title and Quality - but only for the row with the HIGHEST Quality. Like this:

10, 'Artist1', 'Title1', 3
13, 'Artist2', 'Title2', 3


I got as far as this:
SELECT Artist, Title, MAX(Quality)
FROM Table1
GROUP BY Artist, Title
ORDER BY Artist, Title

And this was perfect....until I needed to include the ID to my returned results and this is where I got sunk.

Including MAX(ID) in my SELECT won't work because this gives me the largest ID of the grouping.

What I need is the ID of the row that the MAX(Quality) is returning. And I can't figure out how to get the row ID of the highest quality in my results.

Any help would be appreciated

webfred
Master Smack Fu Yak Hacker

8781 Posts

Posted - 2013-02-27 : 12:37:59
select id, Artist, Title, Quality from
(select row_number() over(partition by Artist, Title order by Quality desc) as rn,* from table1)dt
where rn = 1


Too old to Rock'n'Roll too young to die.
Go to Top of Page

figmo
Starting Member

18 Posts

Posted - 2013-02-27 : 13:35:21
WOW - there's some new stuff. Works great for my SQL Server database. Sadly - I must eventually port this over to SQL Compact Edition which doesn't support OVER PARTITION.

Is there another way to do this?
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-02-27 : 22:50:21
[code]
SELECT t.*
FROM Table t
INNER JOIN (SELECT Artist, Title, MAX(Quality) AS MaxQuality
FROM Table1
GROUP BY Artist, Title
)t1
ON t1.Artist = t.Artist
AND t1.Title = t.Title
AND t1.MaxQuality = t.Quality
ORDER BY t.Artist, t.Title
[/code]

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page
   

- Advertisement -