Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How do you do a GROUP BY on a value that's changed by a CASE?


How do you do a GROUP BY on a value that's changed by a CASE?

Author
Message
Rod
Rod
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1130 Visits: 1930
I've got a SELECT statement which I had hoped would give me what I needed, for counting the number of types of races of people who come into our agency. Here's what the SELECT currently looks like, with values specific only for the first quarter of 2014:


select atr.race,
case atr.Race
when 32 then 'White'
when 1 then 'Black/African American'
when 2 then 'Asian'
when 4 then 'American Indian/Alaskan Native'
when 16 then 'American Indian/Alaskan Native'
when 8 then 'Native Hawaiian/Other Pacific Islander'
when 36 then 'American Indian/Alaskan Native and White'
when 48 then 'American Indian/Alaskan Native and White'
when 34 then 'Asian and White'
when 33 then 'Black/African American and White'
when 5 then 'American Indian/Alaskan Native and Black/African American'
when 17 then 'American Indian/Alaskan Native and Black/African American'
when 10 then 'Asian/Pacific Islander'
else 'Other Multi-Racial'
end as RaceDescription,
yesno.YesNoDesc as 'Hispanic Yes/No', count(*) as racetotal
from dbo.asigeneral as asi
inner join dbo.asiatrsupplement as atr
on atr.clientnumber = asi.clientnumber
and atr.casenumber = asi.casenumber
left join dbo.ASICodesATRYesNo yesno
on atr.hispanicyesno = yesno.YesNo
here asicompleted between '2014-1-1' and '2014-3-31'
group by atr.race, yesno.YesNoDesc
order by atr.race, yesno.YesNoDesc desc



This is a part of a stored procedure (properly parameterized, of course) which is used in a SSRS report. I don't show the individual values returned by atr.Race; the user isn't interested in seeing them. I had hoped that this would capture all of the racial types that come through our doors.

Well, I'm wrong. Now I'd like to do a GROUP BY RaceDescription, but that isn't valid. So how do I get it done?

Kindest Regards,RodConnect with me on LinkedIn.
Luis Cazares
Luis Cazares
SSCrazy Eights
SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)

Group: General Forum Members
Points: 8506 Visits: 18115
You have 2 options:
First one:

WITH CTE AS(
select case atr.Race
when 32 then 'White'
when 1 then 'Black/African American'
when 2 then 'Asian'
when 4 then 'American Indian/Alaskan Native'
when 16 then 'American Indian/Alaskan Native'
when 8 then 'Native Hawaiian/Other Pacific Islander'
when 36 then 'American Indian/Alaskan Native and White'
when 48 then 'American Indian/Alaskan Native and White'
when 34 then 'Asian and White'
when 33 then 'Black/African American and White'
when 5 then 'American Indian/Alaskan Native and Black/African American'
when 17 then 'American Indian/Alaskan Native and Black/African American'
when 10 then 'Asian/Pacific Islander'
else 'Other Multi-Racial'
end as RaceDescription,
yesno.YesNoDesc as 'Hispanic Yes/No'
from dbo.asigeneral as asi
inner join dbo.asiatrsupplement as atr
on atr.clientnumber = asi.clientnumber
and atr.casenumber = asi.casenumber
left join dbo.ASICodesATRYesNo yesno
on atr.hispanicyesno = yesno.YesNo
where asicompleted between '2014-1-1' and '2014-3-31'
)
SELECT RaceDescription,
YesNoDesc,
count(*) as racetotal
FROM CTE
group by race, YesNoDesc
order by race, YesNoDesc desc


2nd option:


select case atr.Race
when 32 then 'White'
when 1 then 'Black/African American'
when 2 then 'Asian'
when 4 then 'American Indian/Alaskan Native'
when 16 then 'American Indian/Alaskan Native'
when 8 then 'Native Hawaiian/Other Pacific Islander'
when 36 then 'American Indian/Alaskan Native and White'
when 48 then 'American Indian/Alaskan Native and White'
when 34 then 'Asian and White'
when 33 then 'Black/African American and White'
when 5 then 'American Indian/Alaskan Native and Black/African American'
when 17 then 'American Indian/Alaskan Native and Black/African American'
when 10 then 'Asian/Pacific Islander'
else 'Other Multi-Racial'
end as RaceDescription,
yesno.YesNoDesc as 'Hispanic Yes/No',
count(*) as racetotal
from dbo.asigeneral as asi
inner join dbo.asiatrsupplement as atr
on atr.clientnumber = asi.clientnumber
and atr.casenumber = asi.casenumber
left join dbo.ASICodesATRYesNo yesno
on atr.hispanicyesno = yesno.YesNo
where asicompleted between '2014-1-1' and '2014-3-31'
group by case atr.Race
when 32 then 'White'
when 1 then 'Black/African American'
when 2 then 'Asian'
when 4 then 'American Indian/Alaskan Native'
when 16 then 'American Indian/Alaskan Native'
when 8 then 'Native Hawaiian/Other Pacific Islander'
when 36 then 'American Indian/Alaskan Native and White'
when 48 then 'American Indian/Alaskan Native and White'
when 34 then 'Asian and White'
when 33 then 'Black/African American and White'
when 5 then 'American Indian/Alaskan Native and Black/African American'
when 17 then 'American Indian/Alaskan Native and Black/African American'
when 10 then 'Asian/Pacific Islander'
else 'Other Multi-Racial'
end, YesNoDesc
order by race, YesNoDesc desc


Note that atr.Race was removed from the column list to be able to group by the descriptions.


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Rod
Rod
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1130 Visits: 1930
Hi Luis,

I like your two solutions. Especially the first one, which I take to be an example of using a common table expression. I've heard of CTE's, but have never used one. I tried that first, but unfortunately it gave me the following errors:


Msg 207, Level 16, State 1, Line 31
Invalid column name 'race'.
Msg 207, Level 16, State 1, Line 31
Invalid column name 'YesNoDesc'.
Msg 207, Level 16, State 1, Line 28
Invalid column name 'YesNoDesc'.
Msg 207, Level 16, State 1, Line 32
Invalid column name 'race'.


The second one was closer to working, but it also gave me an error:


Msg 8127, Level 16, State 1, Line 42
Column "dbo.asiatrsupplement.Race" is invalid in the ORDER BY clause because it is not contained in either an aggregate function or the GROUP BY clause.


Kindest Regards,RodConnect with me on LinkedIn.
Keith Tate
Keith Tate
SSChasing Mays
SSChasing Mays (614 reputation)SSChasing Mays (614 reputation)SSChasing Mays (614 reputation)SSChasing Mays (614 reputation)SSChasing Mays (614 reputation)SSChasing Mays (614 reputation)SSChasing Mays (614 reputation)SSChasing Mays (614 reputation)

Group: General Forum Members
Points: 614 Visits: 979
The error has to do with the fact that it is now a CTE and is returning YesNoDesc field as something else. Try this
WITH CTE AS(
select case atr.Race
when 32 then 'White'
when 1 then 'Black/African American'
when 2 then 'Asian'
when 4 then 'American Indian/Alaskan Native'
when 16 then 'American Indian/Alaskan Native'
when 8 then 'Native Hawaiian/Other Pacific Islander'
when 36 then 'American Indian/Alaskan Native and White'
when 48 then 'American Indian/Alaskan Native and White'
when 34 then 'Asian and White'
when 33 then 'Black/African American and White'
when 5 then 'American Indian/Alaskan Native and Black/African American'
when 17 then 'American Indian/Alaskan Native and Black/African American'
when 10 then 'Asian/Pacific Islander'
else 'Other Multi-Racial'
end as RaceDescription,
yesno.YesNoDesc as 'YesNoDesc'
from dbo.asigeneral as asi
inner join dbo.asiatrsupplement as atr
on atr.clientnumber = asi.clientnumber
and atr.casenumber = asi.casenumber
left join dbo.ASICodesATRYesNo yesno
on atr.hispanicyesno = yesno.YesNo
where asicompleted between '2014-1-1' and '2014-3-31'
)
SELECT RaceDescription,
YesNoDesc,
count(*) as racetotal
FROM CTE
group by RaceDescription, YesNoDesc
order by RaceDescription, YesNoDesc desc

Now this is me guess since there is no sample DDL and DML to test this query. In order to get a solid response back it is always better to provide sample scripts. Please read the first article in my signature



Microsoft Certified Master - SQL Server 2008
Follow me on twitter: @keith_tate

Forum Etiquette: How to post data/code on a forum to get the best help
Rod
Rod
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1130 Visits: 1930
Ah, that makes sense, Keith, thank you.

And sorry that I didn't post the table definitions as well as some data, to get a feel for what the query would likely return.

Kindest Regards,RodConnect with me on LinkedIn.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search