Thread: Need some magic with alternative rows

Need some magic with alternative rows

From
Andreas
Date:
Hi,
I need some magic with alternative rows.

I've got a table with rows relating another table.
mytab (id, name, group_nr, class_nr, fk)

SELECT * FROM mytab
WHERE  (fk = 994010)       OR   ((class_fk = 40) AND (fk = 0))

994001,   Tick,         1,   40,   994010
4001,      Reporting,   1,   40,   0
4002,       LEADS,     2,   40,   0
994003,   Track,      3,    40,  994010
4003,      Details,      3,  40,   0

The rows with fk=0 are defaults that should only be used when there is 
no specific reference to the other table.

Is there a way to remove the default-rows if there exists a fk<>0 row 
that has the same group_nr ?
I'd like to get just:

994001,   Tick,        1,   40,   994010
4002,       LEADS,   2,   40,   0
994003,   Track,      3,   40,  994010


Regards
Andreas



Re: Need some magic with alternative rows

From
Niklas Johansson
Date:
On 7 jun 2008, at 05.04, Andreas wrote:
> Is there a way to remove the default-rows if there exists a fk<>0  
> row that has the same group_nr ?

Yes, use a correlated sub-query:

SELECT * FROM mytab m1
WHERE fk = 994010 OR (class_nr = 40 AND fk = 0 AND NOT EXISTS (SELECT  
1 FROM mytab m2 WHERE m2.group_nr=m1.group_nr AND fk <> 0));




Sincerely,

Niklas Johansson