Can't figure out a case selection

  • I need to write a query to get two numbers: one for this week and one for last week, here is my query for this week, it works fine:

    select sum([numLow]) + sum([numMedium]) + sum([numHigh]) + sum([numZeroScore]) as thisWeek

    from historyTable

    where datediff(day, asAtDate, getdate()) <=7

    A little bit change can get last week

    select sum([numLow]) + sum([numMedium]) + sum([numHigh]) + sum([numZeroScore]) as thisWeek

    from historyTable

    where datediff(day, asAtDate, getdate()) > 7 and datediff(day, asAtDate, getdate()) <=14

    To combine them using union is NOT acceptable as it would produce two rows, what I want is one row with two columns, so I tried to use

    select CurWeek = case

    when datediff(day, asAtDate, getdate()) <=7 then sum([numLow]) + sum([numMedium]) + sum([numHigh]) + sum([numZeroScore]) End,

    PreWeek = case when (datediff(day, asAtDate, getdate()) > 7 and datediff(day, asAtDate, getdate()) <=14) then sum([numLow]) + sum([numMedium]) + sum([numHigh]) + sum([numZeroScore]) end

    from historyTable

    group by asAtDate

    However, it produces result like this:

    CurWeekPreWeek

    NULL130904

    161542NULL

    NULLNULL

    How can I get result like

    CurWeekPreWeek

    161542130904

    Thanks.

  • Something like this:

    SELECT

    SUM(CASE WHEN ht.asAtDate >= DATEADD(DAY, -7, today_midnight)

    THEN ht.[numLow] + ht.[numMedium] + ht.[numHigh] + ht.[numZeroScore]

    ELSE 0 END) AS CurrWeek,

    SUM(CASE WHEN ht.asAtDate < DATEADD(DAY, -7, today_midnight)

    THEN ht.[numLow] + ht.[numMedium] + ht.[numHigh] + ht.[numZeroScore]

    ELSE 0 END) AS PrevWeek

    FROM historyTable ht

    CROSS APPLY (

    SELECT DATEADD(DAY, DATEDIFF(DAY, 0, GETDATE()), 0) AS today_midnight

    ) AS assign_alias_names

    WHERE

    ht.asAtDate >= DATEADD(DAY, -14, today_midnight)

    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".

  • Here's another way:

    ;WITH Preaggregate AS (

    SELECT Grp, [Result] = SUM(numLow) + SUM(numMedium) + SUM(numHigh) + SUM(numZeroScore)

    FROM historyTable h

    CROSS APPLY (

    SELECT [Grp] = CASE

    WHEN h.asAtDate > DATEADD(DAY,-7,CAST(GETDATE() AS DATE)) THEN 'thisWeek'

    WHEN h.asAtDate > DATEADD(DAY,-14,CAST(GETDATE() AS DATE)) THEN 'lastweek'

    --WHEN h.asAtDate > DATEADD(DAY,-21,CAST(GETDATE() AS DATE)) THEN 'weekbeforelast'

    ELSE NULL END

    ) x

    --WHERE h.asAtDate > DATEADD(DAY,-21,CAST(GETDATE() AS DATE))

    WHERE h.asAtDate > DATEADD(DAY,-14,CAST(GETDATE() AS DATE))

    GROUP BY Grp

    )

    SELECT

    [thisWeek] = CASE WHEN Grp = 'thisWeek' THEN Result ELSE 0 END,

    [lastweek] = CASE WHEN Grp = 'lastweek' THEN Result ELSE 0 END,

    [weekbeforelast] = CASE WHEN Grp = 'weekbeforelast' THEN Result ELSE 0 END

    FROM Preaggregate

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

Viewing 3 posts - 1 through 2 (of 2 total)

You must be logged in to reply to this topic. Login to reply