January 30, 2008 at 2:46 pm
Hello,
I have a column in a table that stores time in milliseconds and I want to be able to sum the rows for each day and have a total for the week. I have just started on this and have the following query:
SELECT queueTime, StartDateTime
FROM ContactRoutingDetail WHERE
StartDateTime >= DATEADD(wk,DATEDIFF(wk,0,GETDATE()),0)-1
- CASE WHEN DATENAME(dw,GETDATE()) LIKE 'Sun%' THEN 7 ELSE 0 END
AND StartDateTime < DATEADD(wk,DATEDIFF(wk,0,GETDATE())+1,0)
- CASE WHEN DATENAME(dw,GETDATE()) LIKE 'Sun%' THEN 7 ELSE 0 END
GROUP BY queueTime, StartDateTime
Order By StartDateTime
I'm getting the results for each day of the current week, but I'm stuck on how to SUM them.
TIA,
BP
January 31, 2008 at 6:42 am
This calculates daily totals for the last whole week, monday through saturday:
DROP TABLE #ContactRoutingDetail
GO
CREATE TABLE #ContactRoutingDetail (queueTime INT, StartDateTime DATETIME)
GO
INSERT INTO #ContactRoutingDetail (queueTime, StartDateTime)
SELECT 10, '2008-01-31 11:23:32.937' UNION ALL -- THU
SELECT 10, '2008-01-31 11:22:32.937' UNION ALL
SELECT 10, '2008-01-30 11:21:32.937' UNION ALL -- WED
SELECT 10, '2008-01-30 11:19:32.937' UNION ALL
SELECT 10, '2008-01-29 11:18:32.937' UNION ALL -- TUE
SELECT 10, '2008-01-29 11:17:32.937' UNION ALL
SELECT 10, '2008-01-28 11:16:32.937' UNION ALL -- MON
SELECT 10, '2008-01-28 11:15:32.937' UNION ALL
SELECT 10, '2008-01-27 11:14:32.937' UNION ALL -- SUN
SELECT 10, '2008-01-27 11:13:32.937' UNION ALL
SELECT 10, '2008-01-27 00:00:00.000' UNION ALL
SELECT 10, '2008-01-26 23:59:59.997' UNION ALL -- SAT
SELECT 10, '2008-01-26 11:11:32.937' UNION ALL
SELECT 10, '2008-01-26 00:00:00.000' UNION ALL
SELECT 10, '2008-01-25 11:10:32.937' UNION ALL -- FRI
SELECT 10, '2008-01-25 11:09:32.937' UNION ALL
SELECT 10, '2008-01-24 11:08:32.937' UNION ALL -- THU
SELECT 10, '2008-01-24 11:07:32.937' UNION ALL
SELECT 10, '2008-01-23 11:06:32.937' UNION ALL -- WED
SELECT 10, '2008-01-23 11:05:32.937' UNION ALL
SELECT 10, '2008-01-22 11:04:32.937' UNION ALL -- TUE
SELECT 10, '2008-01-22 11:03:32.937' UNION ALL
SELECT 10, '2008-01-21 11:02:32.937' UNION ALL -- MON
SELECT 10, '2008-01-21 11:01:32.937' UNION ALL
SELECT 10, '2008-01-21 00:00:00.000' UNION ALL
SELECT 10, '2008-01-20 23:59:59.997' UNION ALL -- SUN
SELECT 10, '2008-01-20 11:59:32.937' UNION ALL
SELECT 10, '2008-01-20 00:00:00.000'
GO
DECLARE @Today DATETIME
SET @Today = GETDATE() + 2 -- choose your run day / date for testing
SET DATEFIRST 1 -- monday is now considered the first day of the week (check the current setting)
SELECT SumDayTime, CONVERT(DATETIME, TextDate) AS StartDateTime
FROM (
SELECT SUM(queueTime) AS SumDayTime, CONVERT(CHAR(8), StartDateTime, 112) AS TextDate, DATENAME(dw,StartDateTime) AS DayName, DATEPART(dw, StartDateTime) AS DayNo
FROM #ContactRoutingDetail
WHERE StartDateTime >= CONVERT(CHAR(8), @Today - (DATEPART(dw, @Today)+6), 112)
AND StartDateTime < CONVERT(CHAR(8), @Today - (DATEPART(dw, @Today)+0), 112)
GROUP BY CONVERT(CHAR(8), StartDateTime, 112), DATENAME(dw,StartDateTime), DATEPART(dw, StartDateTime)
) t
ORDER BY t.TextDate
Cheers
ChrisM
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
January 31, 2008 at 2:48 pm
Thanks Chris,
That did the trick. I had to tweak it just a little to suite my exact situation, but I couldn't have done it without your help.
Thanks
BP
January 31, 2008 at 11:35 pm
You're very welcome Brian, and many thanks for the feedback.
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply