Group By Minutes

  • I am trying to get avg duration for each minute. I am not able to group by minute. Startdate is datetime data type and duration is float data type.

    SELECT

    startDate,

    avg(duration) Duration

    FROM Logs with (nolock)

    WHERE Id IN ( 'HI' )

    AND startdate BETWEEN '2013-06-17 08:30:00.000' AND '2013-06-17 10:00:00.000'

    AND sourcemodule = 'panel'

    group by datepart(mi,[startDate])

    order by startdate

    Please help !!!

  • the way you did it is grouping by minute ( not taking year/month/day/hour into account )

    This is how I would do it.

    SELECT

    datepart(mi,[startDate]) as MI,

    min(startDate) as startDate,

    avg(duration) Duration

    FROM Logs with (nolock)

    WHERE Id IN ( 'HI' )

    /* avoid using BETWEEN with datetime datatype */

    AND startdate >='2013-06-17 08:30:00.000' AND startdate < '2013-06-17 10:00:00.000'

    AND sourcemodule = 'panel'

    group by datepart(mi,[startDate])

    order by startdate

    it depends on the simantics of what you need.

    SELECT

    dateadd(mi, datediff(mi,[startDate], 0),0) as MI,

    min(startDate) as startDate,

    avg(duration) Duration

    FROM Logs with (nolock)

    WHERE Id IN ( 'HI' )

    /* avoid using BETWEEN with datetime datatype */

    AND startdate >='2013-06-17 08:30:00.000' AND startdate < '2013-06-17 10:00:00.000'

    AND sourcemodule = 'panel'

    group by dateadd(mi, datediff(mi,[startDate], 0),0) --convert to datetime minute level

    order by startdate

    Johan

    Learn to play, play to learn !

    Dont drive faster than your guardian angel can fly ...
    but keeping both feet on the ground wont get you anywhere :w00t:

    - How to post Performance Problems
    - How to post data/code to get the best help[/url]

    - How to prevent a sore throat after hours of presenting ppt

    press F1 for solution, press shift+F1 for urgent solution 😀

    Need a bit of Powershell? How about this

    Who am I ? Sometimes this is me but most of the time this is me

  • curious_sqldba (6/22/2013)


    I am trying to get avg duration for each minute. I am not able to group by minute. Startdate is datetime data type and duration is float data type.

    SELECT

    startDate,

    avg(duration) Duration

    FROM Logs with (nolock)

    WHERE Id IN ( 'HI' )

    AND startdate BETWEEN '2013-06-17 08:30:00.000' AND '2013-06-17 10:00:00.000'

    AND sourcemodule = 'panel'

    group by datepart(mi,[startDate])

    order by startdate

    Please help !!!

    I'm doing this from memory since I don't have SSMS running at the moment, but I might try something like this (and borrowing from AlzDBA's post):

    SELECT

    result.MI,

    result.StartDate,

    MIN(result.startDate) OVER (PARTITION BY result.MI) AS MinMinute,

    AVG(result.Duration) OVER (PARTITION BY result.startDate) AS Duration

    FROM

    (

    SELECT

    datepart(mi,[startDate]) as MI,

    startDate,

    Duration

    FROM Logs with (nolock)

    WHERE Id IN ( 'HI' )

    /* avoid using BETWEEN with datetime datatype */

    AND startdate >='2013-06-17 08:30:00.000'

    AND startdate < '2013-06-17 10:00:00.000'

    AND sourcemodule = 'panel'

    ) result

    ORDER BY startdate

    Not sure if this logic is exactly correct for your query, but using the OVER clause will let you get

    around some grouping problems when you want to group on different columns in the same query.

     

  • ALZDBA (6/23/2013)


    the way you did it is grouping by minute ( not taking year/month/day/hour into account )

    This is how I would do it.

    SELECT

    datepart(mi,[startDate]) as MI,

    min(startDate) as startDate,

    avg(duration) Duration

    FROM Logs with (nolock)

    WHERE Id IN ( 'HI' )

    /* avoid using BETWEEN with datetime datatype */

    AND startdate >='2013-06-17 08:30:00.000' AND startdate < '2013-06-17 10:00:00.000'

    AND sourcemodule = 'panel'

    group by datepart(mi,[startDate])

    order by startdate

    it depends on the simantics of what you need.

    SELECT

    dateadd(mi, datediff(mi,[startDate], 0),0) as MI,

    min(startDate) as startDate,

    avg(duration) Duration

    FROM Logs with (nolock)

    WHERE Id IN ( 'HI' )

    /* avoid using BETWEEN with datetime datatype */

    AND startdate >='2013-06-17 08:30:00.000' AND startdate < '2013-06-17 10:00:00.000'

    AND sourcemodule = 'panel'

    group by dateadd(mi, datediff(mi,[startDate], 0),0) --convert to datetime minute level

    order by startdate

    This worked , but why am i not seeing data past 9:30? gives only 60 records?I am expecting 90.

  • curious_sqldba (6/23/2013)


    ALZDBA (6/23/2013)


    the way you did it is grouping by minute ( not taking year/month/day/hour into account )

    This is how I would do it.

    SELECT

    datepart(mi,[startDate]) as MI,

    min(startDate) as startDate,

    avg(duration) Duration

    FROM Logs with (nolock)

    WHERE Id IN ( 'HI' )

    /* avoid using BETWEEN with datetime datatype */

    AND startdate >='2013-06-17 08:30:00.000' AND startdate < '2013-06-17 10:00:00.000'

    AND sourcemodule = 'panel'

    group by datepart(mi,[startDate])

    order by startdate

    it depends on the simantics of what you need.

    SELECT

    dateadd(mi, datediff(mi,[startDate], 0),0) as MI,

    min(startDate) as startDate,

    avg(duration) Duration

    FROM Logs with (nolock)

    WHERE Id IN ( 'HI' )

    /* avoid using BETWEEN with datetime datatype */

    AND startdate >='2013-06-17 08:30:00.000' AND startdate < '2013-06-17 10:00:00.000'

    AND sourcemodule = 'panel'

    group by dateadd(mi, datediff(mi,[startDate], 0),0) --convert to datetime minute level

    order by startdate

    This worked , but why am i not seeing data past 9:30? gives only 60 records?I am expecting 90.

    Please ignore, your second query worked. Thanks

Viewing 5 posts - 1 through 4 (of 4 total)

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