Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Time issues


Time issues

Author
Message
DaveDB
DaveDB
SSC-Enthusiastic
SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)

Group: General Forum Members
Points: 113 Visits: 215
Hello,

I have a sql query(using 2005). Please see the grid below. I need to only show time on the hour instead of the half hour but still aggregate my data. The column that I am converting is date time data type but only has the time in 30 minute intervals. Anyone know how I can do this? My apologies if I did not offer enough information. Please ask questions and thank you all very much in advance.

Times ACD Other

8:30AM --12 --10
9:00AM --48 --0
9:30AM --20 --27
10:00AM --0 --0
10:30AM --0 --0
11:00AM --47 --0
11:30AM --33 --0
12:00PM --0 --0
12:30PM --0 --0
1:00PM --22 --0
1:30PM --0 --0
2:00PM --53 --0
Lowell
Lowell
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14956 Visits: 38953
can you post the data as consumable sql stateemtns we can paste into SSMS, along with the datatypes?


something like this is an example

;WITH MyCTE([Times],[ACD],[Other],[Outb])
AS
(
SELECT '8:30AM','0:00:00','0:00:00','0:00:00' UNION ALL
SELECT '9:00AM','0:09:48','0:00:00','0:00:23' UNION ALL
SELECT '9:30AM','0:15:20','0:02:27','0:00:00' UNION ALL
SELECT '10:00AM','0:00:00','0:00:00','0:01:32' UNION ALL
SELECT '10:30AM','0:00:00','0:00:00','0:00:00' UNION ALL
SELECT '11:00AM','0:15:47','0:00:00','0:00:00' UNION ALL
SELECT '11:30AM','0:00:33','0:00:00','0:00:00' UNION ALL
SELECT '12:00PM','0:00:00','0:00:00','0:00:00' UNION ALL
SELECT '12:30PM','0:00:00','0:00:00','0:00:00' UNION ALL
SELECT '1:00PM','0:05:22','0:00:00','0:00:13' UNION ALL
SELECT '1:30PM','0:00:04','0:00:00','0:12:25' UNION ALL
SELECT '2:00PM','0:05:53','0:00:00','0:00:00' UNION ALL
SELECT ''
)
SELECT * FROM MyCTE;



Lowell

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

Lowell
Lowell
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14956 Visits: 38953
and somethign from my snippets, which is grouping data into half hour intervals:

With MySampleData
(AgentID,State,StartTime,EndTime,Duration)
AS (
SELECT '1234','NotReady',Cast('2011-04-05 08:00:00' AS datetime),Cast('2011-04-05 08:00:05' AS datetime),'5' UNION ALL
SELECT '1234','Ready','2011-04-05 08:00:05','2011-04-05 08:01:00','55' UNION ALL
SELECT '1234','Busy','2011-04-05 08:01:00','2011-04-05 08:03:00','120' UNION ALL
SELECT '1234','ACW','2011-04-05 08:03:00','2011-04-05 08:03:10','10' UNION ALL
SELECT '1234','Ready','2011-04-05 08:03:10','2011-04-05 08:05:00','110' UNION ALL
SELECT '1234','NotReady','2011-04-05 08:05:00','2011-04-05 08:35:00','1800' UNION ALL
SELECT '1234','Ready','2011-04-05 08:35:00','2011-04-05 08:40:00','300'
)

, Calendar( StartTime, EndTime ) AS (
SELECT Cast('2011-04-05 07:30' AS datetime), Cast('2011-04-05 08:00' AS datetime)
UNION ALL
SELECT Cast('2011-04-05 08:00' AS datetime), Cast('2011-04-05 08:30' AS datetime)
UNION ALL
SELECT Cast('2011-04-05 08:30' AS datetime), Cast('2011-04-05 09:00' AS datetime)
)

, Interval_Details AS (
SELECT d.AgentID, c.StartTime AS Interval
, DateDiff(ss
, CASE WHEN c.StartTime > d.StartTime THEN c.StartTime ELSE d.Starttime END
, CASE WHEN c.EndTime < d.EndTime THEN c.EndTime ELSE d.Endtime END
) AS IntervalLength
, [State]
FROM MySampleData AS d
INNER JOIN Calendar AS c
ON d.StartTime < c.EndTime
AND c.StartTime < d.EndTime
)

SELECT
AgentID
, Interval
, Sum(IntervalLength) AS LoginTime
, Sum(CASE [State] WHEN 'Ready' THEN IntervalLength ELSE 0 END) AS ReadyTime
, Sum(CASE [State] WHEN 'NotReady' THEN IntervalLength ELSE 0 END) AS NotReadyTime
, Sum(CASE [State] WHEN 'ACW' THEN IntervalLength ELSE 0 END) AS ACWTime
FROM Interval_Details
GROUP BY AgentID, Interval





Lowell

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

DaveDB
DaveDB
SSC-Enthusiastic
SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)SSC-Enthusiastic (113 reputation)

Group: General Forum Members
Points: 113 Visits: 215
Thanks again Lowell. Here is my code...

SELECT INTERVALSTART
,RIGHT(INTERVALSTART, 7) as Times
,dbo.ConvToHours(Sum(ACDTIME)) as [ACD Time]
,dbo.ConvToHours(SUM(AUXINTIME+ACWINTIME)) as [Other Inb Call Time]
,dbo.ConvToHours(SUM(ACWOUTOFFTIME + AUXOUTOFFTIME)) as [Outb Ext Call Time]
,SUM(ACWOUTCALLS - ACWOUTOFFCALLS + AUXOUTCALLS - AUXOUTOFFCALLS) as [Outb Int Calls]
,dbo.ConvToHours(SUM(ACWOUTTIME - ACWOUTOFFTIME + AUXOUTTIME - AUXOUTOFFTIME)) as [Outb Int Call Time]
,SUM(ACDCALLS + AUXOUTCALLS + AUXINCALLS + ACWOUTCALLS + ACWINCALLS) as [Total Calls]
,dbo.ConvToHours(SUM(ACDTIME + AUXOUTTIME + AUXINTIME + ACWOUTTIME + ACWINTIME)) as [Total Call Time]
FROM oadb.hCmsAgent A
LEFT JOIN dbo.Agent_Groups G ON A.logid = G.logid
WHERE convert(varchar(15), INTERVALSTART, 101) = '12/13/2013' --convert(varchar(15),getdate(),101)
GROUP BY A.LOGID, datepart(hh,INTERVALSTART),INTERVALSTART,ITEM_NAME,Logname
ORDER BY A.LogId, datepart(hh,INTERVALSTART)
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4249 Visits: 6431
Are you perhaps looking for something like this?


WITH SampleData (Times, ACD, Other) AS
(
SELECT CAST('08:30' AS DATETIME), -12, -10
UNION ALL SELECT CAST('09:00' AS DATETIME), -48, -0
UNION ALL SELECT CAST('09:30' AS DATETIME), -20, -27
UNION ALL SELECT CAST('10:00' AS DATETIME), -0, -0
UNION ALL SELECT CAST('10:30' AS DATETIME), -0, -0
UNION ALL SELECT CAST('11:00' AS DATETIME), -47, -0
UNION ALL SELECT CAST('11:30' AS DATETIME), -33, -0
UNION ALL SELECT CAST('12:00' AS DATETIME), -0, -0
UNION ALL SELECT CAST('12:30' AS DATETIME), -0, -0
UNION ALL SELECT CAST('13:00' AS DATETIME), -22, -0
UNION ALL SELECT CAST('13:30' AS DATETIME), -0, -0
UNION ALL SELECT CAST('14:00' AS DATETIME), -53, -0
)
SELECT Times=DATEADD(hour, DATEDIFF(hour, 0, Times), 0)
,ACD=SUM(ACD), Other=SUM(Other)
FROM SampleData
GROUP BY DATEADD(hour, DATEDIFF(hour, 0, Times), 0);





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
David Burrows
David Burrows
SSCertifiable
SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)

Group: General Forum Members
Points: 7965 Visits: 9417

SELECT CONVERT(char(2),Times,108)+':00' AS [Times],SUM(ACD) AS [ACD],SUM(Other) AS [Other]
FROM SampleData
GROUP BY CONVERT(char(2),Times,108)
ORDER BY CONVERT(char(2),Times,108) ASC




Far away is close at hand in the images of elsewhere.

Anon.


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