January 22, 2013 at 1:41 pm
Hi geniuses,
It is possible to have a 'GROUP BY' inside a CASE Statement? In order to Sum my values properly?
What I got so far:
CASE WHEN KTVID = '12345' AND KTVValueType = '02.KTVSCHAF' THEN Value ELSE 0 END
Thanks
Regards
January 22, 2013 at 1:47 pm
davdam8 (1/22/2013)
Hi geniuses,It is possible to have a 'GROUP BY' inside a CASE Statement? In order to Sum my values properly?
What I got so far:
CASE WHEN KTVID = '12345' AND KTVValueType = '02.KTVSCHAF' THEN Value ELSE 0 END
Thanks
Regards
That is NOT a group by but there does not appear to be anything wrong with that.
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
January 22, 2013 at 9:11 pm
This article may help
______________________________________________________________________________Never argue with an idiot; Theyll drag you down to their level and beat you with experience
January 24, 2013 at 9:41 am
You can avoid group by altogether by using the OVER() method when using aggregates (I think this is for SQL2008 and higher).
IF OBJECT_ID('tempdb..#TempTable') IS NOT NULL
DROP TABLE #TempTable
CREATE TABLE #TempTable (
[ID] INT IDENTITY(1,1) NOT NULL,
[Age] INT NULL,
[Sex] CHAR(1) NULL,
[School] VARCHAR(20) NULL,
PRIMARY KEY (ID))
INSERT INTO #TempTable
SELECT 22,'M','Thomasville'
UNION
SELECT 19,'M','Thomasville'
UNION
SELECT 31,'F','Polytechnic'
UNION
SELECT 20,'M','Thomasville'
UNION
SELECT 32,'F','Polytechnic'
UNION
SELECT 27,'F','Thomasville'
UNION
SELECT 22,'M','Polytechnic'
UNION
SELECT 18,'M','Thomasville'
UNION
SELECT 40,'F','Thomasville'
SELECT * FROM #TempTable
DECLARE
@Category VARCHAR(50)
SET @Category = 'Sex'
SELECT DISTINCT
(CASE
WHEN @Category = 'Sex' THEN Sex
WHEN @Category = 'School' THEN School
END) AS Category
,(CASE
WHEN @Category = 'Sex' THEN MIN(Age) OVER (PARTITION BY Sex)
WHEN @Category = 'School' THEN MIN(Age) OVER (PARTITION BY School)
END) AS MinAge
,(CASE
WHEN @Category = 'Sex' THEN AVG(Age) OVER (PARTITION BY Sex)
WHEN @Category = 'School' THEN AVG(Age) OVER (PARTITION BY School)
END) AS Average
,(CASE
WHEN @Category = 'Sex' THEN MAX(Age) OVER (PARTITION BY Sex)
WHEN @Category = 'School' THEN MAX(Age) OVER (PARTITION BY School)
END) AS MaxAge
FROM
#TempTable
SET @Category = 'School'
SELECT DISTINCT
(CASE
WHEN @Category = 'Sex' THEN Sex
WHEN @Category = 'School' THEN School
END) AS Category
,(CASE
WHEN @Category = 'Sex' THEN MIN(Age) OVER (PARTITION BY Sex)
WHEN @Category = 'School' THEN MIN(Age) OVER (PARTITION BY School)
END) AS MinAge
,(CASE
WHEN @Category = 'Sex' THEN AVG(Age) OVER (PARTITION BY Sex)
WHEN @Category = 'School' THEN AVG(Age) OVER (PARTITION BY School)
END) AS Average
,(CASE
WHEN @Category = 'Sex' THEN MAX(Age) OVER (PARTITION BY Sex)
WHEN @Category = 'School' THEN MAX(Age) OVER (PARTITION BY School)
END) AS MaxAge
FROM
#TempTable
Output all data:
IDAgeSexSchool
118MThomasville
219MThomasville
320MThomasville
422MPolytechnic
522MThomasville
627FThomasville
731FPolytechnic
832FPolytechnic
940FThomasville
Output selected data:
CategoryMinAgeAverageMaxAge
F273240
M182022
CategoryMinAgeAverageMaxAge
Polytechnic222832
Thomasville182440
January 24, 2013 at 9:45 am
You can use CASE w/i a GROUP BY.
You can also use CASE w/i a SUM to control which values get aggregated. For example:
SELECT
a, b,
SUM(CASE WHEN KTVID = '12345' AND KTVValueType = '02.KTVSCHAF' THEN Value ELSE 0 END) AS KTVID_12345_02_Total,
SUM(Value) AS All_Values_Total
FROM
dbo.tablename
GROUP BY
a, b
SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
January 24, 2013 at 11:51 am
There's really no limit to what you can do with grouping and case statements. The OVER() clause really makes thing easy. You can even combine all the aggregates in the same CASE statement, then use the DelimitedSplit8K function and a PIVOT to show the aggregated results:
IF OBJECT_ID('tempdb..#TempTable') IS NOT NULL
DROP TABLE #TempTable
CREATE TABLE #TempTable (
[ID] INT IDENTITY(1,1) NOT NULL,
[Age] INT NULL,
[Sex] CHAR(1) NULL,
[School] VARCHAR(20) NULL,
PRIMARY KEY (ID))
INSERT INTO #TempTable
SELECT 22,'M','Thomasville'
UNION
SELECT 19,'M','Thomasville'
UNION
SELECT 31,'F','Polytechnic'
UNION
SELECT 20,'M','Thomasville'
UNION
SELECT 32,'F','Polytechnic'
UNION
SELECT 27,'F','Thomasville'
UNION
SELECT 22,'M','Polytechnic'
UNION
SELECT 18,'M','Thomasville'
UNION
SELECT 40,'F','Thomasville'
IF OBJECT_ID('tempdb..#ResultsTable') IS NOT NULL
DROP TABLE #ResultsTable
CREATE TABLE #ResultsTable (
[ID] INT IDENTITY(1,1) NOT NULL,
[Sex] VARCHAR(10) NULL,
[SexMin] INT NULL,
[SexAvg] DECIMAL(5,2) NULL,
[SexMax] INT NULL,
[School] VARCHAR(20) NULL,
[SchMin] INT NULL,
[SchAvg] DECIMAL(5,2) NULL,
[SchMax] INT NULL,
PRIMARY KEY (ID))
INSERT INTO #ResultsTable
SELECT
(CASE
WHEN Sex = 'M' THEN 'Male'
WHEN Sex = 'F' THEN 'Female'
END
) AS Sex
,MAX(MinAge1) OVER (PARTITION BY Sex) AS SexMin
,MAX(CAST(AvgAge1 AS DECIMAL(5,2))) OVER (PARTITION BY Sex) AS SexAvg
,MAX(MaxAge1) OVER (PARTITION BY Sex) AS SexMax
,School
,MAX(MinAge2) OVER (PARTITION BY School) AS SchMin
,MAX(CAST(AvgAge2 AS DECIMAL(5,2))) OVER (PARTITION BY School) AS SchAvg
,MAX(MaxAge2) OVER (PARTITION BY School) AS SchMax
FROM
(
SELECT
Sex
,(CASE
WHEN ItemNumSex = 1 THEN 'MinAge1'
WHEN ItemNumSex = 2 THEN 'AvgAge1'
WHEN ItemNumSex = 3 THEN 'MaxAge1'
END) AS AggTypeSex
,ItemSex AS AggAgeSex
,School
,(CASE
WHEN ItemNumSch = 1 THEN 'MinAge2'
WHEN ItemNumSch = 2 THEN 'AvgAge2'
WHEN ItemNumSch = 3 THEN 'MaxAge2'
END) AS AggTypeSch
,ItemSch AS AggAgeSch
FROM
(
SELECT
R.Sex
,R.School
,ds1.ItemNumber AS ItemNumSex
,ds1.Item AS ItemSex
,ds2.ItemNumber AS ItemNumSch
,ds2.Item AS ItemSch
FROM
(
SELECT
Sex
,School
,(CASE
WHEN Sex IS NOT NULL
THEN
CAST(MIN(Age) OVER (PARTITION BY Sex) AS VARCHAR(10))
+','+CAST(AVG(CAST(Age AS DECIMAL(5,2))) OVER (PARTITION BY Sex) AS VARCHAR(10))
+','+CAST(MAX(Age) OVER (PARTITION BY Sex) AS VARCHAR(10))
END) AS AggSex
,(CASE
WHEN School IS NOT NULL
THEN
CAST(MIN(Age) OVER (PARTITION BY School) AS VARCHAR(10))
+','+CAST(AVG(CAST(Age AS DECIMAL(5,2))) OVER (PARTITION BY School) AS VARCHAR(10))
+','+CAST(MAX(Age) OVER (PARTITION BY School) AS VARCHAR(10))
END) AS AggSchool
FROM
#TempTable
) AS R
CROSS APPLY
dbo.DelimitedSplit8K(R.AggSex,',') AS ds1
CROSS APPLY
dbo.DelimitedSplit8K(R.AggSchool,',') AS ds2
) AS R1
) AS A
PIVOT
(
MAX(AggAgeSex) FOR AggTypeSex IN (MinAge1,AvgAge1,MaxAge1)
) AS SexAggregates
PIVOT
(
MAX(AggAgeSch) FOR AggTypeSch IN (MinAge2,AvgAge2,MaxAge2)
) AS SchAggregates
SELECT DISTINCT
Sex AS Category
,SexMin AS AgeMin
,SexAvg AS AgeAvg
,SexMax AS AgeMax
FROM
#ResultsTable
UNION ALL
SELECT DISTINCT
School AS Category
,SchMin AS AgeMin
,SchAvg AS AgeAvg
,SchMax AS AgeMax
FROM
#ResultsTable
Output:
CategoryAgeMinAgeAvgAgeMax
Female2732.5040
Male1820.2022
Polytechnic2228.3332
Thomasville1824.3340
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply