Average hourly rowcounts

  • Hi

    I have a table with RunId, RunDateTime, RowCount

    RunDateTime will be every 15 minutes.

    1 2013-03-21 10:00:00 20

    2 2013-03-21 10:15:00 30

    3 2013-03-21 10:30:00 20

    4 2013-03-21 10:45:00 25

    5 2013-03-21 11:00:00 15

    I want to retrieve hourly average rowcounts

    Like

    AvgHourlyDateTime AbgRowCount

    -----------------------------------------------------------------

    2013-03-21 10:00:00To2013-03-21 11:00 (20+30+20+25+15)/5

    How can I do this

  • You should start to help our helpers (link at the bottom of my signature), by supplying DDL and sample data insert scripts instead of "I have table like that..." thing.

    But anyway:

    declare @ihaveatablelikethat table (RunId int, RunDateTime datetime, [RowCount] int)

    insert @ihaveatablelikethat

    select 1, '2013-03-21 10:00:00', 20

    union select 2, '2013-03-21 10:15:00', 30

    union select 3, '2013-03-21 10:30:00', 20

    union select 4, '2013-03-21 10:45:00', 25

    union select 5, '2013-03-21 11:00:00', 15

    union select 6, '2013-03-21 11:30:00', 20

    union select 7, '2013-03-21 11:45:00', 25

    union select 8, '2013-03-21 12:00:00', 15

    select DATEADD(HOUR,DATEPART(HOUR,RunDateTime),CAST(CAST(RunDateTime AS DATE) AS DATETIME)) DHFrom

    ,DATEADD(HOUR,DATEPART(HOUR,RunDateTime)+1,CAST(CAST(RunDateTime AS DATE) AS DATETIME)) DHTo

    ,AVG([RowCount])

    from @ihaveatablelikethat

    group by CAST(RunDateTime AS DATE), DATEPART(HOUR,RunDateTime)

    Please note: You cannot logically include record for 10:00:00 and 11:00:00 in to the same group (for "Hour 10 to 11"), otherwise, these records will be double counted in bordering groups Hour 9 to 10 and Hour 11 to 12.

    I made grouping based on "included" from hour to "excluded" to hour.

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • SELECT

    DATEADD(HOUR, DATEDIFF(HOUR, 0, RunDateTime), 0) AS AvgHourlyDateTime,

    --DATEADD(MILLISECOND, -3, DATEADD(HOUR, DATEDIFF(HOUR, 0, RunDateTime) + 1, 0)) AS AvgHourlyEndDateTime,

    AVG([RowCount]) AS AbgRowCount

    FROM @ihaveatablelikethat

    GROUP BY

    DATEADD(HOUR, DATEDIFF(HOUR, 0, RunDateTime), 0)

    --,DATEADD(MILLISECOND, -3, DATEADD(HOUR, DATEDIFF(HOUR, 0, RunDateTime) + 1, 0))

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

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

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