• 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