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

Time issues Expand / Collapse
Author
Message
Posted Friday, December 13, 2013 12:57 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Monday, February 24, 2014 11:06 AM
Points: 109, 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
Post #1522853
Posted Friday, December 13, 2013 1:00 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 5:47 PM
Points: 12,910, Visits: 32,020
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1522854
Posted Friday, December 13, 2013 1:02 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 5:47 PM
Points: 12,910, Visits: 32,020
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1522856
Posted Friday, December 13, 2013 1:07 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Monday, February 24, 2014 11:06 AM
Points: 109, 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)
Post #1522857
Posted Sunday, December 15, 2013 5:52 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 8:30 PM
Points: 3,631, Visits: 5,281
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!
Post #1523072
Posted Monday, December 16, 2013 8:36 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 7:48 AM
Points: 7,100, Visits: 6,927
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.

Post #1523271
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse