December 8, 2010 at 10:12 am
I need to work out the total monthly time an emplyee is working given the signon and signoff times. All I need to use is the time the employee first signed on in the morning and the last time the employee signedoff. I don't need the time inbetween.
Table is:
ResourceID (int), Site (int), DateKey(yyyymmdd), TimeKey(hh:mm:ss), EventType(int).
Event type of 2 indicates signon ,3 signoff and 4 idle
This is the sample data:
ResourceId Site DateKey TimeKey EventType
1 1 20100901 80010 2
1 1 20100901 113001 3
1 1 20100901 122014 2
1 1 20100901 153223 3
1 1 20100901 153814 2
1 1 20100901 161503 3
1 1 20100902 80010 2
1 1 20100902 113001 3
1 1 20100902 122014 2
1 1 20100902 153223 3
1 1 20100902 153814 2
1 1 20100902 161503 3
2 1 20100901 80010 2
2 1 20100901 113001 3
2 1 20100901 122014 2
2 1 20100901 153223 3
2 1 20100901 153814 2
2 1 20100901 161503 3
2 1 20100902 80010 2
2 1 20100902 113001 3
2 1 20100902 122014 2
2 1 20100902 153223 3
2 1 20100902 153814 2
2 1 20100902 161503 3
Is there a simpler way to do this without using temporary tables?
Thanks
December 8, 2010 at 11:12 am
Any chance you can post the sample data and DDL like in the first link of my sig? Will make life much easier.
Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.
For better assistance in answering your questions[/url] | Forum Netiquette
For index/tuning help, follow these directions.[/url] |Tally Tables[/url]
Twitter: @AnyWayDBA
December 8, 2010 at 11:40 am
:-)Thanks. Here it is:
if (object_id('tempdb..#Astime') is not null) drop table #Astime
create table #Astime (ResourceId smallint, Site smallint,
DateKey int, TimeKey int, EventType smallint)
insert into #Astime
select 1, 1, 20100901, 80010,2
union
select 1, 1, 20100901, 113001,3
union
select 1, 1, 20100901, 122014,2
union
select 1, 1, 20100901, 153223,3
union
select 1, 1, 20100901, 153814,2
union
select 1, 1, 20100901, 161503,3
union
select 1, 1, 20100902, 80010,2
union
select 1, 1, 20100902, 122014,2
union
select 1, 1, 20100902, 153223,3
union
select 1, 1, 20100902, 153814,2
union
select 1, 1, 20100902, 161510,3
union
select 2, 1, 20100901, 80015,2
union
select 2, 1, 20100901, 113001,3
union
select 2, 1, 20100901, 122014,2
union
select 2, 1, 20100901, 153223,3
union
select 2, 1, 20100901, 153814,2
union
select 2, 1, 20100901, 161523,3
union
select 2, 1, 20100902, 80010,2
union
select 2, 1, 20100902, 122014,2
union
select 2, 1, 20100902, 153223,3
union
select 2, 1, 20100902, 153814,2
union
select 2, 1, 20100902, 161520,3
select * from #Astime
December 8, 2010 at 12:18 pm
I broke this into CTE's because it's easier to see the methodology that way. You could do this all in one query if you wanted. The key is the two subqueries, which are listed as cte and cte2.
Note one of the larger issues is turning your separate date and time stamps into usable values.
/*
if (object_id('tempdb..#Astime') is not null) drop table #Astime
create table #Astime (ResourceId smallint, Site smallint,
DateKey int, TimeKey int, EventType smallint)
insert into #Astime
select 1, 1, 20100901, 80010,2
union
select 1, 1, 20100901, 113001,3
union
select 1, 1, 20100901, 122014,2
union
select 1, 1, 20100901, 153223,3
union
select 1, 1, 20100901, 153814,2
union
select 1, 1, 20100901, 161503,3
union
select 1, 1, 20100902, 80010,2
union
select 1, 1, 20100902, 122014,2
union
select 1, 1, 20100902, 153223,3
union
select 1, 1, 20100902, 153814,2
union
select 1, 1, 20100902, 161510,3
union
select 2, 1, 20100901, 80015,2
union
select 2, 1, 20100901, 113001,3
union
select 2, 1, 20100901, 122014,2
union
select 2, 1, 20100901, 153223,3
union
select 2, 1, 20100901, 153814,2
union
select 2, 1, 20100901, 161523,3
union
select 2, 1, 20100902, 80010,2
union
select 2, 1, 20100902, 122014,2
union
select 2, 1, 20100902, 153223,3
union
select 2, 1, 20100902, 153814,2
union
select 2, 1, 20100902, 161520,3
*/
;WITH cte AS
(SELECT
ResourceID,
DateKey,
MIN( TimeKey) AS StartTime
FROM
#Astime
WHERE
EventType = 2
GROUP BY
ResourceID,
DateKey
)
,cte2 AS
(SELECT
ResourceID,
DateKey,
MAX( TimeKey) AS EndTime
FROM
#Astime
WHERE
EventType = 3
GROUP BY
ResourceID,
DateKey
)
,cte3 AS
(SELECT
c.ResourceID,
c.DateKey,
c.StartTime,
ISNULL( c2.EndTime, 115959) AS EndTime
FROM
cte AS c
LEFT JOIN
cte2 AS c2
Onc.ResourceID = c2.ResourceID
AND c.DateKey = c2.DateKey
)
, cte4 AS
(SELECT
ResourceID,
CONVERT( DateTime, CONVERT( VARCHAR(20), DateKey)) AS DateKey,
DATEADD( mm, DATEDIFF( mm, 0, CONVERT( DATETIME, CONVERT( VARCHAR(20), DateKey))), 0) AS MonthStartDateKey,
--REVERSE( STUFF( STUFF( REVERSE( CONVERT( VARCHAR(30), StartTime)), 3, 0, ':'), 6, 0, ':')) AS test
Convert( Datetime, '1/1/1900 ' + REVERSE( STUFF( STUFF( REVERSE( CONVERT( VARCHAR(30), StartTime)), 3, 0, ':'), 6, 0, ':'))) AS StartTime,
Convert( Datetime, '1/1/1900 ' + REVERSE( STUFF( STUFF( REVERSE( CONVERT( VARCHAR(30), endTime)), 3, 0, ':'), 6, 0, ':'))) AS EndTime
FROM
cte3
)
SELECT
ResourceID,
MonthStartDateKey,
SUM( DATEDIFF(n, StartTime, EndTime)) AS TotalMinutesWorkedInMonth
FROM
cte4
GROUP BY
ResourceID,
MonthStartDateKey
Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.
For better assistance in answering your questions[/url] | Forum Netiquette
For index/tuning help, follow these directions.[/url] |Tally Tables[/url]
Twitter: @AnyWayDBA
December 8, 2010 at 1:01 pm
Thanks. I am learning CTE and so it was helpful when you broke it down, but how do you put all this in one query?:-)
December 8, 2010 at 2:24 pm
KS-321165 (12/8/2010)
Thanks. I am learning CTE and so it was helpful when you broke it down, but how do you put all this in one query?:-)
SELECT
drvStart.ResourceID,
DATEADD( mm, DATEDIFF( mm, 0, drvStart.DateKey), 0) AS MonthStartDateKey,
SUM( DATEDIFF(n, StartTime, ISNULL( EndTime, CONVERT( DATETIME, '1/1/1900 23:59:59')))) AS TotalMinutesWorkedInMonth
FROM
(SELECT
ResourceID,
CONVERT( DateTime, CONVERT( VARCHAR(20), DateKey)) AS DateKey,
MIN( Convert( Datetime, '1/1/1900 ' + REVERSE( STUFF( STUFF( REVERSE( CONVERT( VARCHAR(30), TimeKey)), 3, 0, ':'), 6, 0, ':')))) AS StartTime
FROM
#Astime
WHERE
EventType = 2
GROUP BY
ResourceID,
DateKey
) AS drvStart
LEFT JOIN
(SELECT
ResourceID,
CONVERT( DateTime, CONVERT( VARCHAR(20), DateKey)) AS DateKey,
MAX( Convert( Datetime, '1/1/1900 ' + REVERSE( STUFF( STUFF( REVERSE( CONVERT( VARCHAR(30), TimeKey)), 3, 0, ':'), 6, 0, ':')))) AS EndTime
FROM
#Astime
WHERE
EventType = 3
GROUP BY
ResourceID,
DateKey
) AS drvEnd
ONdrvStart.ResourceID = drvEnd.ResourceID
AND drvStart.DateKey = drvEnd.DateKey
GROUP BY
drvStart.ResourceID,
DATEADD( mm, DATEDIFF( mm, 0, drvStart.DateKey), 0)
Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.
For better assistance in answering your questions[/url] | Forum Netiquette
For index/tuning help, follow these directions.[/url] |Tally Tables[/url]
Twitter: @AnyWayDBA
December 8, 2010 at 2:29 pm
Thank You! You saved me a ton of time.
December 8, 2010 at 2:34 pm
KS-321165 (12/8/2010)
Thank You! You saved me a ton of time.
You're welcome. If there's any bits and pieces of that you don't understand come back and ask. You're going to have to maintain that, so you really need to understand all the things I did against your dates and times to make them work.
Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.
For better assistance in answering your questions[/url] | Forum Netiquette
For index/tuning help, follow these directions.[/url] |Tally Tables[/url]
Twitter: @AnyWayDBA
December 9, 2010 at 8:24 pm
1. Craig, can I have an autographed photo of your brain for Chistmas?
2. This is totally cool. I'm trying to figure it all out. I think I'm doing pretty well. Couple questions/confirmations (re: Post #1032106):
CONVERT( DateTime, CONVERT( VARCHAR(20), DateKey)) AS DateKey
I guess this means you can't directly convert an INT to DateTime?
DATEADD( mm, DATEDIFF( mm, 0, CONVERT( DATETIME, CONVERT( VARCHAR(20), DateKey))), 0) AS MonthStartDateKey
Okay, this confuses me. I have taken it apart from the inside out, I understand what DATEADD and DATEDIFF do, but I don't understand the use of "0" here...?
And the REVERSE, STUFF, REPEAT...
, as much as I'd like to pretend to understand it, I don't.
If you feel like elaborating on any of this, I'd love to learn what exactly you're doing.
December 9, 2010 at 9:17 pm
autoexcrement (12/9/2010)
1. Craig, can I have an autographed photo of your brain for Chistmas?2. This is totally cool. I'm trying to figure it all out. I think I'm doing pretty well. Couple questions/confirmations (re: Post #1032106):
CONVERT( DateTime, CONVERT( VARCHAR(20), DateKey)) AS DateKey
I guess this means you can't directly convert an INT to DateTime?
The answer to this is "it depends" - specifically on what you're storing in that int. If you are storing a date in YYYYMMDD format, then no. If you are storing an offset from 01/01/1900, then yes.
DATEADD( mm, DATEDIFF( mm, 0, CONVERT( DATETIME, CONVERT( VARCHAR(20), DateKey))), 0) AS MonthStartDateKey
Okay, this confuses me. I have taken it apart from the inside out, I understand what DATEADD and DATEDIFF do, but I don't understand the use of "0" here...?
If you were to run "SELECT CONVERT(DATETIME, 0)", you will see that this is converted to 01/01/1900.
What the code is doing is getting the number of month boundaries crossed between 01/01/1900 and the other date. It then adds this number of months to 01/01/1900. The end result of this is that it will always return the first of the month for the specified date.
And the
REVERSE, STUFF, REPEAT...
, as much as I'd like to pretend to understand it, I don't.If you feel like elaborating on any of this, I'd love to learn what exactly you're doing.
The REVERSE/STUFF/STUFF/REVERSE is taking the TimeKey field (time represented as an integer). Since leading zeros are not shown, anything before 10am will only be 5 digits instead of 6. So the intent is to add the colons between the hours/minutes and minutes/seconds. SELECT REVERSE('80101') will return 10108. We now can put those colons in the proper places. (STUFF adds the colon in the proper position.) Once finished, you have 10:10:8. You now need to reverse this again to have the valid time: 8:01:01.
Edit: you could also do STUFF(STUFF(RIGHT('0' + CONVERT(VARCHAR(6), TimeKey), 6),5,0,':'),3,0,':')
. This converts the TimeKey to a string, prefixes it with a '0', takes the right 6 characters, and adds the colons.
Does this explain it all?
Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
December 9, 2010 at 9:37 pm
Wayne, yes, thank you. That explains it completely. So, using your example of a time "80101", the code would (working from the inside out) transform it thusly:
80101 (original)
10108 (reversed)
10:108 (stuff 3rd position with colon)
10:10:8 (stuff 6th position with colon)
8:01:01 (re-reverse)
So, all that remains to be explained is...are you guys some kind of freaking sql wizards or what? What hope is there for us normal people with you lot lurking around? 🙂
Thanks, I continue to be in awe at the creativity, intelligence, and amazing patience and tutelage available on this site.
EDIT: P.S. Your double-stuffed remix is tasty too!
December 10, 2010 at 2:08 am
autoexcrement (12/9/2010)
Wayne, yes, thank you. That explains it completely. So, using your example of a time "80101", the code would (working from the inside out) transform it thusly:80101 (original)
10108 (reversed)
10:108 (stuff 3rd position with colon)
10:10:8 (stuff 6th position with colon)
8:01:01 (re-reverse)
On the money.
So, all that remains to be explained is...are you guys some kind of freaking sql wizards or what? What hope is there for us normal people with you lot lurking around? 🙂
Thanks, I continue to be in awe at the creativity, intelligence, and amazing patience and tutelage available on this site.
Plenty of hope, I've been at this ten years or so, Wayne longer. Give yourself time. Eventually you remember the functions offhand and then start coming up with strange and interesting ways to twist them together like burnt pretzels. 🙂
Oh, and thanks.
Btw, regarding the brain? Sorry, no can do. After the amount of alcohol I've poisoned it with over the years I'm afraid it'll spontaneously combust if it is allowed an oxygen source. 😉
Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.
For better assistance in answering your questions[/url] | Forum Netiquette
For index/tuning help, follow these directions.[/url] |Tally Tables[/url]
Twitter: @AnyWayDBA
December 10, 2010 at 7:34 am
autoexcrement (12/9/2010)
Wayne, yes, thank you. That explains it completely. So, using your example of a time "80101", the code would (working from the inside out) transform it thusly:80101 (original)
10108 (reversed)
10:108 (stuff 3rd position with colon)
10:10:8 (stuff 6th position with colon)
8:01:01 (re-reverse)
So, all that remains to be explained is...are you guys some kind of freaking sql wizards or what? What hope is there for us normal people with you lot lurking around? 🙂
Thanks, I continue to be in awe at the creativity, intelligence, and amazing patience and tutelage available on this site.
EDIT: P.S. Your double-stuffed remix is tasty too!
One thing to note: The order that you do the STUFF calls can change what you're doing.
Above, you inserted the colons from left to right. What this means is that you have to account for that colon in the subsequent calls to STUFF.
The alternative is to insert them from right-to-left. Showing just them, it would be:
1010:8 (stuff 5th position with colon)
10:10:8 (stuff 3rd position with colon)
You'll find a lot of folks will do it this way just to take that variable out of the way.
Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
December 10, 2010 at 7:40 am
autoexcrement (12/9/2010)
So, all that remains to be explained is...are you guys some kind of freaking sql wizards or what?
But of course! :w00t:
What hope is there for us normal people with you lot lurking around? 🙂
Well, you see, that's the whole point. By lurking around, you are hopefully acquiring this knowledge transfer that's going on. Reinforce it by practice (aka, help out here on the forums). Don't get upset if what you come up with isn't "the best"; instead, learn from it. (If you look into the forums here, you'll find that most learning really goes on after the first answer was posted, with even well-versus folks learning from others. Even "the guru himself" (Jeff) recently learned a new safety check that can be applied to the infamous "quirky update" to guarantee things were processed correctly. (The learning never stops.....)
Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
December 10, 2010 at 7:45 am
Craig Farrell (12/10/2010)
Plenty of hope, I've been at this ten years or so, Wayne longer. Give yourself time. Eventually you remember the functions offhand and then start coming up with strange and interesting ways to twist them together like burnt pretzels. 🙂
And, now that you understand what's going on here... you'll never forget it. So, you've been exposed to dateadd(datediff) to get the first of the month (change the datepart to get the first of any period!), and using reverse/stuff/reverse. Not too bad for one thread!
EDIT: Check out the common date/time routines link in my signature!
Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
Viewing 15 posts - 1 through 15 (of 15 total)
You must be logged in to reply to this topic. Login to reply