Skip to Main Content

SQL & PL/SQL

Announcement

For appeals, questions and feedback about Oracle Forums, please email oracle-forums-moderators_us@oracle.com. Technical questions should be asked in the appropriate category. Thank you!

Interested in getting your voice heard by members of the Developer Marketing team at Oracle? Check out this post for AppDev or this post for AI focus group information.

Select 'best' row?

ngilbertMay 9 2008 — edited May 12 2008
This might be a pretty simple question but....

If I have a table like this:

Name Col1
A Bad
A Good
A Best
B Good
C Bad
D Bad
D Best

Can someone help me figure out a way to select out the one best row for each name such that I get

Name Col1
A Best
B Good
C Bad
D Best

The idea being that I need one row per name - if a Col1 = 'Best' row isn't found I use Col1 = 'Good' and if that isn't found I use Col1 = 'Bad'

Thanks for any help

Comments

SomeoneElse

Analytics are good for things like this:

SQL> select name
  2        ,col1
  3  from
  4  (
  5     select name
  6           ,col1
  7           ,dense_rank() over (partition by name order by case col1
  8                                                               when 'Best' then 1
  9                                                               when 'Good' then 2
 10                                                               when 'Bad'  then 3
 11                                                               else 0
 12                                                          end) dr
 13     from   t
 14  )
 15  where dr = 1
 16  ;

N COL1
- ----------
A Best
B Good
C Bad
D Best

Message was edited by: SomeoneElse

(forgot the ELSE)

ngilbert
Awed and grateful. Thank you very much!
Vadim Tropashko-Oracle
select name, Best(col1) from tbl
group by name

Ok, no joking:

select name, reverse(max(reverse(col1))) from tbl
group by name
572471
select name, max(col1) keep (dense_rank first order by decode(lower(col1),'best',1,'good',2,'bad',3,4)) 
from <table> 
group by name
Aketi Jyuuzou
create table PointTable(Name,Col1) as
select 'A','Bad'   from dual union all
select 'A','Good'  from dual union all
select 'A','Best'  from dual union all
select 'B','Good'  from dual union all
select 'C','Bad'   from dual union all
select 'D','Bad'   from dual union all
select 'D','Best'  from dual union all
select 'E','Best'  from dual union all
select 'E','worst' from dual union all
select 'F','Bad'   from dual union all
select 'F','worst' from dual;
select Name,Col1
from (select Name,Col1,
      rank() over(partition by Name
                  order by case Col1
                           when 'Best'  then 1
                           when 'Good'  then 2
                           when 'Bad'   then 3
                           when 'worst' then 4 end) as Rn
      from PointTable)
where Rn = 1
order by Name;

or

select distinct Name,
First_Value(Col1)
over(partition by Name
order by case Col1
         when 'Best'  then 1
         when 'Good'  then 2
         when 'Bad'   then 3
         when 'worst' then 4 end) as Col1
      from PointTable
order by Name;
Name  COL1
----  -----
A     Best
B     Good
C     Bad
D     Best
E     Best
F     Bad
450441
select name, reverse(max(reverse(col1))) from tbl
group by name
Well spotted.
1 - 6
Locked Post
New comments cannot be posted to this locked post.

Post Details

Locked on Jun 9 2008
Added on May 9 2008
6 comments
1,360 views