Current Order Date and Average Count of Orders for Three Prior Days

  • Want to get

    1) the OrderDate and

    2) the daily average of total Orders for that day and two previous days where there are orders.

    As an example, I use the Shipping.Orders Table from the Northwind database from SQL Server 2005.

    USE Northwind

    GO

    SELECT OrderDate, COUNT(OrderDate)

    FROM Shipping.Orders

    WHERE OrderDate Between '04-30-1998' AND '05-06-1998'

    GROUP BY OrderDate

    ORDER BY 1 DESC

    With this basic query you can see there are 4 orders on 5/6, 4 orders on 5/5 and 3 orders on 5/4.

    Total orders for the three day period is 11. Average of 3.67.

    Total orders for the next three day period starting from the next OrderDate is 10. Average of 3.33

    So I would want the output to look like

    OrderDate AverageOrderCount

    5/6 3.67

    5/5 3.33

    and so on...

    SELECT COUNT(OrderDate)

    FROM Shipping.Orders

    WHERE OrderDate Between '04-30-1998' AND '05-06-1998'

    ORDER BY 1 DESC

  • Total number of orders for the next 3 days is 7: 4 + 3 + 0.

    Can you explain your logic more precisely?

    _____________
    Code for TallyGenerator

  • I can try. Can you explain what "ext" means precisely?

  • I fixed the typo.

    _____________
    Code for TallyGenerator

  • Here's one solution but it is quite lengthy. I'm sure there is a more efficient answer. So please show me your wisdom!

    I used a different column though - RequiredDate instead of OrderDate.

    Here's the query to check the result set against. And below that - my inefficient, but working solution.

    --Check Table

    USE Northwind

    GO

    SELECT RequiredDate, COUNT(RequiredDate)

    FROM Shipping.Orders

    WHERE RequiredDate Between '1998-05-01' AND '1998-06-11'

    GROUP BY RequiredDate

    ORDER BY 1 DESC

    ------- Inefficient Solution --------

    DECLARE @counter int,

    @counter2 int,

    @date smalldatetime,

    @scope int

    SELECT @counter = 1,

    @counter2 = 1

    DECLARE @Time TABLE (

    ID int IDENTITY (1,1),

    timex smalldatetime

    )

    --Gather dates to report on

    -- Note: not all dates have a RequiredDate

    INSERT @Time

    (timex)

    SELECT DISTINCT RequiredDate

    FROM Shipping.Orders

    WHERE RequiredDate BETWEEN '1998-05-01' AND '1998-06-11'

    ORDER BY 1 DESC

    -- Select 1st Date

    SELECT @date = (SELECT timex FROM @Time WHERE ID = 1)

    -- Create Results table

    DECLARE @Results TABLE (

    t_RequiredDate smalldatetime,

    t_count int

    )

    SELECT @scope = SCOPE_IDENTITY()

    -- Set @scope to number of RequiredDates in @Time

    WHILE @counter < @scope

    BEGIN

    INSERT @Results

    SELECT timex,

    (SELECT COUNT(RequiredDate)

    FROM Shipping.Orders

    WHERE RequiredDate IN (SELECT distinct TOP 3 RequiredDate -- Only want count of last three RequiredDates

    FROM Shipping.Orders

    WHERE RequiredDate

    BETWEEN DATEADD(day, -10, @date) AND @date order by 1 desc) --Goes back 10 because not all dates have values

    )

    FROM @Time

    WHERE ID = @counter2

    SELECT @counter2 = @counter2 + 1

    SELECT @date = (SELECT timex FROM @Time WHERE ID = @counter2)

    SELECT @counter = @counter + 1

    END

    -- Retrieve Results

    SELECT t_RequiredDate,

    LTRIM(STR(CAST(t_count as float)/ 3, 4,2)) --obtain average

    FROM @Results

    ORDER BY 1 DESC

  • Still it's not clear what are trying to achieve.

    As for me the solution you posted is logically wrong.

    But I cannot be sure because I don't have an idea what's the task you need to solve.

    _____________
    Code for TallyGenerator

  • Here's a shorter version, but I know there is still room for improvement.

    DECLARE @date smalldatetime,

    @counter int

    SELECT @date = '1998-06-11',

    @counter = 1

    DECLARE @Results TABLE (

    t_RequiredDate smalldatetime,

    t_count int

    )

    -- Select @counter to desired result set size

    WHILE @counter < 10

    BEGIN

    WHILE (SELECT DISTINCT RequiredDate FROM Shipping.Orders WHERE RequiredDate = @date) IS NULL

    BEGIN

    SELECT @date = DATEADD(day, -1, @date)

    END

    INSERT @Results

    SELECT RequiredDate,

    (SELECT COUNT(RequiredDate)

    FROM Shipping.Orders

    WHERE RequiredDate IN (SELECT distinct TOP 3 RequiredDate -- Only want count of last three RequiredDates

    FROM Shipping.Orders

    WHERE RequiredDate

    BETWEEN DATEADD(day, -10, @date) AND @date order by 1 desc) --Goes back 10 because not all dates have values

    )

    FROM Shipping.Orders

    WHERE RequiredDate = @date

    SELECT @date = DATEADD(day, -1, @date)

    SELECT @counter = @counter + 1

    END

    SELECT DISTINCT t_RequiredDate,

    LTRIM(STR(CAST(t_count as float)/ 3, 4,2)) --obtain average

    FROM @Results

    ORDER BY 1 DESC

  • David,

    that was not much help.

    You cannot build any right query unless you know what you are querying for.

    I still see the same logical error (according to my understanding) in the approach, but I cannot tell for sure if it's an error in fact.

    Can you tell IN PLAIN ENGLISH WHAT ARE YOU LOOKING FOR?

    What does it really mean: the day and 2 earlier days?

    Which days to be taken as "earlier days"?

    _____________
    Code for TallyGenerator

  • It kind of seems to me David is looking for a rolling three day average. If today is the third day of the month, say 10/3, then he needs the average for 10/1+10/2+10/3. Tomorrow will be the fourth day of the month so he will need the average for 10/2+10/3+10/4, and so on.

    Greg
    _________________________________________________________________________________________________
    The glass is at one half capacity: nothing more, nothing less.

  • David I do not have the sample databases, so I improvised. I think this may be what you are looking to do? I am fairly sure this is *not* the way you want to do this because it creates a triangular join, but it works.

    --Create test table and populate with data

    IF OBJECT_ID('tblOrders','u') IS NOT NULL

    DROP TABLE tblorders

    CREATE TABLE tblOrders

    (

    ID INT IDENTITY(1,1),

    ORDER_DT SMALLDATETIME,

    )

    INSERT INTO tblOrders (ORDER_DT)

    SELECT '10/5/2007' UNION ALL

    SELECT '10/5/2007' UNION ALL

    SELECT '10/5/2007' UNION ALL

    SELECT '10/5/2007' UNION ALL

    SELECT '10/4/2007' UNION ALL

    SELECT '10/4/2007' UNION ALL

    SELECT '10/4/2007' UNION ALL

    SELECT '10/3/2007' UNION ALL

    SELECT '10/2/2007' UNION ALL

    SELECT '10/2/2007' UNION ALL

    SELECT '10/2/2007' UNION ALL

    SELECT '10/1/2007' UNION ALL

    SELECT '10/3/2007' UNION ALL

    SELECT '10/6/2007' UNION ALL

    SELECT '10/6/2007' UNION ALL

    SELECT '10/6/2007' UNION ALL

    SELECT '10/6/2007' UNION ALL

    SELECT '10/6/2007' UNION ALL

    SELECT '10/6/2007' UNION ALL

    SELECT '10/6/2007' UNION ALL

    SELECT '10/3/2007' UNION ALL

    SELECT '10/2/2007' UNION ALL

    SELECT '10/1/2007' UNION ALL

    SELECT '10/6/2007'

    --Create temp table to hold total # orders per day

    IF OBJECT_ID('TempDB..#Temp','u') IS NOT NULL

    DROP TABLE #Temp

    CREATE TABLE #Temp

    (

    ID INT IDENTITY(1,1),

    ORDER_DT SMALLDATETIME,

    DT_Total FLOAT,

    )

    --Populate temp table

    INSERT INTO #Temp

    SELECT

    ORDER_DT,

    DT_Total = COUNT(order_dt)

    FROM tblOrders

    GROUP BY order_dt

    ORDER BY order_dt DESC

    --Find 3 day average

    SELECT

    t1.ORDER_DT,

    t1.DT_Total,

    (

    SELECT

    ROUND(SUM(t2.dt_total)/3,1)

    FROM #temp t2

    WHERE t2.order_dt = t1.order_dt

    OR t2.order_dt = t1.order_dt - 1

    OR t2.order_dt = t1.order_dt -2

    ) AS Total

    FROM #Temp t1

    Greg
    _________________________________________________________________________________________________
    The glass is at one half capacity: nothing more, nothing less.

  • Greg,

    in the example given your approach gives 3 days Orders Count for 05/05/1998.

    OP expects it to be 10.

    That's why I asked about the logic to be implemented.

    _____________
    Code for TallyGenerator

  • Original thread seemed pretty darned clear... but I could be wrong...

    This should do it...

    --===== If the temp table exists, drop it

    IF OBJECT_ID('TempDB..#SandBox') IS NOT NULL

    DROP TABLE #SandBox

    --===== Create and populate the temp table with daily counts

    SELECT IDENTITY(INT,1,1) AS RowNum,

    OrderDate,

    COUNT(OrderDate) AS DailyCount,

    CAST(NULL AS DECIMAL(9,2)) AS Rolling3DayAvg

    INTO #SandBox

    FROM Orders

    WHERE OrderDate BETWEEN '04-30-1998' AND '05-06-1998'

    GROUP BY OrderDate

    ORDER BY OrderDate

    --===== Walk the 3 day rolling average

    UPDATE #SandBox

    SET Rolling3DayAvg = (SELECT AVG(DailyCount*1.0) FROM #SandBox sb1 WHERE sb1.RowNum BETWEEN sb2.RowNum-2 AND sb2.RowNum)

    FROM #SandBox sb2

    WHERE sb2.RowNum >= 3

    --===== Display the results

    SELECT * FROM #SandBox

    ORDER BY RowNum DESC

    ... and no triangular joins

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • ... and, if there are any questions about possible performance, lets use the good ol' million row test table I keep around...


    --===========================================================================================

    -- Build a million rows of test data. THIS IS JUST TO BUILD TEST DATA AND IS NOT PART

    -- OF THE SOLUTION!!!!

    --===========================================================================================

    IF OBJECT_ID('TempDB..#TestData','U') IS NOT NULL

    DROP TABLE #TestData

    --===== Create and populate a 1,000,000 row test table.

    -- Column RowNum has a range of 1 to 1,000,000 unique numbers

    -- Column "SomeInt" has a range of 1 to 50,000 non-unique numbers

    -- Column "SomeString" has a range of "AA" to "ZZ" non-unique 2 character strings

    -- Column "SomeNumber has a range of 0.0000 to 99.9999 non-unique numbers

    -- Column "SomeDate" has a range of >=01/01/2000 and <01/01/2010 non-unique date/times

    -- Takes about 40 seconds to execute.

    SELECT TOP 1000000

    RowNum = IDENTITY(INT,1,1),

    SomeInt = CAST(RAND(CAST(NEWID() AS VARBINARY))*50000+1 AS INT),

    SomeString = CHAR(STR(RAND(CAST(NEWID() AS VARBINARY))*25+65))

    + CHAR(STR(RAND(CAST(NEWID() AS VARBINARY))*25+65)),

    SomeNumber = CAST(RAND(CAST(NEWID() AS VARBINARY))*100 AS MONEY),

    SomeDate = DATEADD(dd,DATEDIFF(dd,0,CAST(RAND(CAST(NEWID() AS VARBINARY))*3653.0+36524.0 AS DATETIME)),0)

    INTO #TestData

    FROM Master.dbo.SysColumns sc1,

    Master.dbo.SysColumns sc2 --Lack of join criteria makes this a CROSS-JOIN

    --===== A table is not properly formed unless a Primary Key has been assigned

    ALTER TABLE #TestData

    ADD PRIMARY KEY CLUSTERED (RowNum)


    Ok... let's use the same code we used before ...

    --===========================================================================================

    -- Demo same solution as before but the input is 1 million rows and 10 years worth of dates.

    -- How long do you thing this method will take? Try it...

    --===========================================================================================

    --===== If the temp table exists, drop it

    IF OBJECT_ID('TempDB..#SandBox') IS NOT NULL

    DROP TABLE #SandBox

    --===== Create and populate the temp table with daily counts

    SELECT IDENTITY(INT,1,1) AS RowNum,

    SomeDate,

    COUNT(SomeDate) AS DailyCount,

    CAST(NULL AS DECIMAL(9,2)) AS Rolling3DayAvg

    INTO #SandBox

    FROM #TestData

    GROUP BY SomeDate

    ORDER BY SomeDate

    --===== A table is not properly formed unless a Primary Key has been assigned

    ALTER TABLE dbo.#SandBox

    ADD PRIMARY KEY CLUSTERED (RowNum)

    --===== Walk the 3 day rolling average

    UPDATE #SandBox

    SET Rolling3DayAvg = (SELECT AVG(DailyCount*1.0) FROM #SandBox sb1 WHERE sb1.RowNum BETWEEN sb2.RowNum-2 AND sb2.RowNum)

    FROM #SandBox sb2

    WHERE sb2.RowNum >= 3

    --===== Display the results

    SELECT * FROM #SandBox

    ORDER BY RowNum DESC

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Thanks Jeff! I was hoping you would respond. You always have such brilliant responses!!

    Many thanks!!

  • What about days having no orders?

    What if nobody made any order on Tuesday?

    Jeff, don't you think the Thursday calculation should include zero orders for Tuesday, not whatever number for Monday?

    Sorry, there are no smart answers on stupid questions.

    _____________
    Code for TallyGenerator

Viewing 15 posts - 1 through 15 (of 23 total)

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