Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Group By Minutes Expand / Collapse
Author
Message
Posted Saturday, June 22, 2013 11:26 PM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Yesterday @ 8:33 PM
Points: 1,285, Visits: 2,963
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 !!!
Post #1466497
Posted Sunday, June 23, 2013 2:15 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, October 9, 2014 10:42 AM
Points: 6,731, Visits: 8,480
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


Don't drive faster than your guardian angel can fly ...
but keeping both feet on the ground won't get you anywhere

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


Need a bit of Powershell? How about this

Who am I ? Sometimes this is me but most of the time this is me
Post #1466509
Posted Sunday, June 23, 2013 8:20 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Sunday, September 29, 2013 1:24 AM
Points: 429, Visits: 1,721
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.

 
Post #1466526
Posted Sunday, June 23, 2013 7:21 PM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Yesterday @ 8:33 PM
Points: 1,285, Visits: 2,963
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.
Post #1466555
Posted Sunday, June 23, 2013 10:14 PM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Yesterday @ 8:33 PM
Points: 1,285, Visits: 2,963
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
Post #1466566
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse