December 19, 2013 at 1:43 am
Hi
here is my data structure:
Check-In-Type:
I = Check-in
O = Check-out
Userid | Date | Time | Check-In-Type
001|1-Jan-2013|12:30|I
001|1-Jan-2013|12:31|I
001|1-Jan-2013|12:35|I
002|1-Jan-2013|12:30|I
002|1-Jan-2013|12:31|I
002|1-Jan-2013|12:35|I
002|1-Jan-2013|12:31|O
002|1-Jan-2013|12:35|O
As you can see I have multiple users doing multiple check-In in the attendance device. I need to know best time-in and best-time-out based on user and date. I am unable to get the best-time-in and out.
select userid, date, time,
row_number() over (partition by userid order by date desc) as bubu
into #temp2
from #temp
December 19, 2013 at 2:08 am
Best for the business or best for the user?
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
December 19, 2013 at 2:16 am
The Attendance System devices are a separate software. The data in there table is just like this. Some people do time-in and no time outs. I have to manage it in my reporting system and the report template is just like this.
Any help is much appreciated.
Thanks
December 19, 2013 at 6:39 am
uzwa ul haque (12/19/2013)
The Attendance System devices are a separate software. The data in there table is just like this. Some people do time-in and no time outs. I have to manage it in my reporting system and the report template is just like this.Any help is much appreciated.
Thanks
There's not enough information to provide sensible help yet.
What do you want to do if there's a time in with no time out? A time out with no time in?
Writing the code won't be difficult if you can tell us the business rules.
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
December 23, 2013 at 5:58 pm
They say at Christmas it is better to give than to receive.
So I will give you back your sample data in a manner that is consumable and thereby the helpers on this forum can give you better help.
WITH SampleData (Userid, [DateTime], [Check-In-Type]) AS
(
SELECT '001',CAST('2013-01-01 12:30' AS DATETIME),'I'
UNION ALL SELECT '001','2013-01-01 12:31','I'
UNION ALL SELECT '001','2013-01-01 12:35','I'
UNION ALL SELECT '002','2013-01-01 12:30','I'
UNION ALL SELECT '002','2013-01-01 12:31','I'
UNION ALL SELECT '002','2013-01-01 12:35','I'
UNION ALL SELECT '002','2013-01-01 12:31','O'
UNION ALL SELECT '002','2013-01-01 12:35','O'
)
SELECT Userid
,DateOfCheckInOut=DATEADD(day, DATEDIFF(day, 0, [DateTime]), 0)
,MinCheckIn=MIN(CASE [Check-In-Type] WHEN 'I' THEN [DateTime] END)
,MaxCheckOut=MAX(CASE [Check-In-Type] WHEN 'O' THEN [DateTime] END)
FROM SampleData
GROUP BY DATEADD(day, DATEDIFF(day, 0, [DateTime]), 0), Userid;
I've also proposed a solution that may be close to what you're looking for. As Chris said though, you need to be more clear on your business rules before we can be sure of what you're trying to do.
In particular, I was quite unsure of the data types of your columns, so I converted the Date/Time to a single column of DATETIME data type. If yours are truly separate, you can combine them and use what I gave you. Better if your table already has them combined. Keeping them separate will just cause you no end to headaches later on.
Merry Christmas!
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply