Thanks to all who responded.
I have taken the solution provided by Birgitta
I had never used CTEs, so I'm excited to use this method.
Thanks
Mike
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Birgitta Hauser
Sent: Saturday, November 20, 2010 8:59 AM
To: 'Midrange Systems Technical Discussion'
Subject: AW: Problems with Group by and case in sql
I'd use at least 2 Common table expressions:
With a as (Select distinct PRDPT
from PROVRDPT00
Where PRNAME = 'BRANDTNS'),
b as (Select PLBEMP, PLBGG1, PLBHRS,
Case When PLBPTP = 'CO' Then 'CALLOUT'
Else 'OVERTIME'
End FldCase
From PRLBH
Where PLBEDT = 20100228
and PLBPTP in ('CO','OH', '6D','7D','OG')) Select EEUN, EEDPT, PLBEMP, EENAM, PLBBG1, FldCase, Sum(PLBHRS)
From b Join EEMP on PLBEMP = EENO
Join a on PRDEPT = EEDPT
Where EETDT = 0
Group By EEUN, EEDPT, PLBEMP, EENAM, PLBBG1, FldCase
Order By ... whatever sequence you need
Mit freundlichen Grüßen / Best regards
Birgitta Hauser
"Shoot for the moon, even if you miss, you'll land among the stars." (Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok) "What is worse than training your staff and losing them? Not training them and keeping them!"
-----Ursprüngliche Nachricht-----
Von: midrange-l-bounces@xxxxxxxxxxxx
[mailto:midrange-l-bounces@xxxxxxxxxxxx] Im Auftrag von Smith, Mike
Gesendet: Friday, 19. November 2010 22:04
An: Midrange Systems Technical Discussion
Betreff: Problems with Group by and case in sql
I have a SQL I'm trying to write. My first attempt is trying to use a case statement in a GROUP BY clause.
SELECT eeun, eedpt, plbemp, eenam, plbbg1, plbptp, sum(plbhrs)
FROM PRLBH, EEMP
WHERE PLBEMP = EEENO and PLBPTP in('CO','OH', '6D','7D','OG')
and EETDT = 0 and EEDPT in (select PRDPT from PROVRDPT00 where
PRNAME = 'BRANDTNS')
and PLBEDT = 20100228
GROUP BY PLBEMP,EENAM,PLBBG1,EEUN, EEDPT ,
case PLBPTP when 'CO' then 'CALLOUT'
Else 'OT'
End
I get errors telling me PLBPTP or expression in select list not valid
If I remove the case on the group by I get results, but not what I would like ideally.
In researching this, I came across a CTE example that I worked like this
with x (a,b,c,d,e,f) as (SELECT eeun, eedpt, plbemp, eenam, plbbg1,
sum(plbhrs) case plbptp when 'CO' then 'CALLOUT'
when 'OT' then 'OVERTIME'
when '6D' then 'OVERTIME'
when '7D' then 'OVERTIME'
when 'OG' then 'OVERTIME'
else 'OTHERS'
end
from PRLBH, EEMP
WHERE PLBEMP = EEENO
and PLBPTP in('CO','OH', '6D','7D','OG') and EETDT = 0 and EEDPT
in (select PRDPT from PROVRDPT00 where PRNAME = 'BRANDTNS') and
PLBEDT = 20100228)
select a,b,c,d,e,f from x group by c,d,e,a,b,f
On this one I get token PLBPTP not valid on my case statement.
This one will work if I remove the sum(plbhrs), but I need it in my final results.
Any idea what I'm doing wrong on either one of these.
Thanks for any help
Mike
NOTICE: This message, including any attachment, is intended as a confidential and privileged communication. If you have received this message in error, or are not the named recipient(s), please immediately notify the sender and delete this message.
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list To post a message email: MIDRANGE-L@xxxxxxxxxxxx To subscribe, unsubscribe, or change list options,
visit:
http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx Before posting, please take a moment to review the archives at
http://archive.midrange.com/midrange-l.
As an Amazon Associate we earn from qualifying purchases.