January 8, 2009 at 2:06 am
Hi all,
I need to produce a report which shows the number of man-hours (in minutes) worked for each hour of the day. In other words, if two people have worked between 9am and 10am, then in my report, the hour 9 would show 120 minutes. If one person worked from 11am to 11.35am, then the hour 11 would show 35 minutes. I have some working code, but wondered if there are better alternatives - it took a lot of head-scratching for me to get to this point! 😛
I have a StaffTimeRecord table which shows the time the worker clocked in and clocked out as well as other information, but for the purpose of this post, I have simplified it to the 2 columns I am interested in. My tally table is called Tally, with one column called n - I haven't created that in the following code snippet.
CREATE TABLE #StaffTimeRecord
(StartTime DATETIME,
EndTime DATETIME)
GO
INSERT INTO #StaffTimeRecord
SELECT '2009-01-02 07:42', '2009-01-02 15:49'
UNION ALL
SELECT '2009-01-02 03:12', '2009-01-02 19:20'
GO
SELECT TOP 24 t.n,
SUM(
DATEDIFF(mi,
CASE
WHEN s.StartTime > (DATEADD(mi, n * 60,DATEADD(dd, DATEDIFF(dd, 0, StartTime), 0)))
THEN
s.StartTime
ELSE
DATEADD(mi, n * 60,DATEADD(dd, DATEDIFF(dd, 0, StartTime), 0))
END
,
CASE
WHEN s.EndTime < (DATEADD(mi, (n + 1) * 60,DATEADD(dd, DATEDIFF(dd, 0, StartTime), 0)))
THEN
s.EndTime
ELSE
DATEADD(mi, (n + 1) * 60,DATEADD(dd, DATEDIFF(dd, 0, StartTime), 0))
END
)
) TotalMinutes
FROM
tally t
INNER JOIN
#StaffTimeRecord s
ON
n >= DATEPART(hh, s.StartTime)
AND
n <= DATEPART(hh, s.EndTime)
GROUP BY n
GO
DROP TABLE #StaffTimeRecord
I hope this makes sense, and would be interested in seeing alternative ways of handling this scenario.
Simon
January 8, 2009 at 5:30 am
did you try this ?
CREATE TABLE #StaffTimeRecord
(
StartTime DATETIME
, EndTime DATETIME
)
GO
set nocount on
INSERT INTO #StaffTimeRecord
SELECT '2009-01-02 07:42'
, '2009-01-02 15:49'
UNION ALL
SELECT '2009-01-02 03:12'
, '2009-01-02 19:20'
UNION ALL
SELECT '2009-01-02 00:02'
, '2009-01-02 01:20'
UNION ALL
SELECT '2009-01-02 22:02'
, '2009-01-02 22:20'
GO
Select *
from #StaffTimeRecord
order by starttime, endtime
-- use t.n - 1 unless your tally table starts with 0 (zero)
SELECT TOP 24
t.n - 1 as [Hour]
, isnull(SUM(case when DATEPART(hh, s.StartTime) = t.n -1
then ((t.n - 1) * 60) - DATEDIFF(mi,DATEADD(dd, DATEDIFF(dd, 0, StartTime), 0), s.StartTime)
else 0
end
+ case when DATEPART(hh, s.EndTime) = t.n -1
then DATEPART(mi, s.EndTime)
when DATEPART(hh, s.EndTime) > t.n -1
then 60
else 0
end
),0) TotalMinutes
, count(*) as NEmployees
FROM tally t
left JOIN #StaffTimeRecord s
ON n >= DATEPART(hh, s.StartTime) + 1
AND n <= DATEPART(hh, s.EndTime) + 1
GROUP BY n
GO
DROP TABLE #StaffTimeRecord
go
Johan
Learn to play, play to learn !
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[/url]
- 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
January 8, 2009 at 9:46 am
Or you could have the hour as a datetime to cope with multiple days. Something like:
SELECT D.HourStart
    ,SUM
    (
        CASE
            WHEN D.HourStart >= S.StartTime AND D.HourEnd < S.EndTime
            THEN 60
            WHEN D.HourStart < S.StartTime AND D.HourEnd > S.EndTime
            THEN 60 - DATEDIFF(mi, D.HourStart, S.StartTime) - DATEDIFF(mi, S.EndTime, D.HourEnd)
            WHEN D.HourStart < S.StartTime
            THEN 60 - DATEDIFF(mi, D.HourStart, S.StartTime)
            ELSE 60 - DATEDIFF(mi, S.EndTime, D.HourEnd)
        END
    ) AS TotalMinutes
FROM
(
    SELECT DATEADD(hour, T.N -1, D1.StaffDate)
        ,DATEADD(hour, T.N, D1.StaffDate)
    FROM Tally T
        CROSS JOIN
        (
            SELECT DATEADD(day, DATEDIFF(day, 0, StartTime), 0)
            FROM #StaffTimeRecord
            UNION
            SELECT DATEADD(day, DATEDIFF(day, 0, EndTime), 0)
            FROM #StaffTimeRecord
        ) D1 (StaffDate)
    WHERE T.N < 25
) D (HourStart, HourEnd)
    JOIN #StaffTimeRecord S
        ON D.HourEnd > S.StartTime
            AND D.HourStart <= S.EndTime
GROUP BY D.HourStart
ORDER BY HourStart
Viewing 3 posts - 1 through 2 (of 2 total)
You must be logged in to reply to this topic. Login to reply