SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Group By Minutes


Group By Minutes

Author
Message
curious_sqldba
curious_sqldba
SSCertifiable
SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)

Group: General Forum Members
Points: 7056 Visits: 3696
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 !!!
ALZDBA
ALZDBA
One Orange Chip
One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)

Group: General Forum Members
Points: 28507 Visits: 8986
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


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


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


press F1 for solution, press shift+F1 for urgent solution :-D


Need a bit of Powershell? How about this

Who am I ? Sometimes this is me Alien but most of the time this is me Hehe
Steven Willis
Steven Willis
SSCommitted
SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)

Group: General Forum Members
Points: 1929 Visits: 1721
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.

 
curious_sqldba
curious_sqldba
SSCertifiable
SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)

Group: General Forum Members
Points: 7056 Visits: 3696
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
curious_sqldba
SSCertifiable
SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)

Group: General Forum Members
Points: 7056 Visits: 3696
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
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search