July 17, 2013 at 7:20 am
Hi All,
I am not sure if I am posting on correct forum, but I need to find a solution to this.
This must be really stupid to ask such simple things but somehow I am not able to figure it out.
I have a table which has EmployeeID, Status, dateTime.
Everytime a user Enters the door there is a record with EmployeeID, Staus (IN/OUT) and datetime.
I need a store procedure or a query which will help me generate a report how much time the user Inside the Room (Basically difference between In and Out). There is once twist that the employee can go in and come out multiple times.
I need to generate a report for employees each visit as well as a total time spend report for the day.
Note: If there is a requirement to change the tables, I can do it and modify the software to make an entry accordingly.
Thanks in advance.
July 17, 2013 at 7:48 am
Hi and welcome to the forums. In order to help we will need a few things:
1. Sample DDL in the form of CREATE TABLE statements
2. Sample data in the form of INSERT INTO statements
3. Expected results based on the sample data
Please take a few minutes and read the first article in my signature for best practices when posting questions.
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
July 17, 2013 at 8:29 am
Create Table If not exists
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[tblEMPLog]') AND type in (N'U'))
DROP TABLE [dbo].[tblEMPLog]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[tblEMPLog]') AND type in (N'U'))
BEGIN
CREATE TABLE [dbo].[tblEMPLog](
[ID] [int] IDENTITY(1,1) NOT NULL,
[EmpID] [int] NOT NULL,
[Status] [varchar](50) NOT NULL,
[Htime] [datetime] NOT NULL,
CONSTRAINT [PK_tblEMPLog] PRIMARY KEY CLUSTERED
(
[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
END
GO
Insert some data in the Table
INSERT [dbo].[tblEMPLog] ([ID], [EmpID], [Status], [Htime]) VALUES (1, N'IN', CAST(0x0000A1FE0100D7B4 AS DateTime))
INSERT [dbo].[tblEMPLog] ([ID], [EmpID], [Status], [Htime]) VALUES (1, N'OUT', CAST(0x0000A1FE01016454 AS DateTime))
INSERT [dbo].[tblEMPLog] ([ID], [EmpID], [Status], [Htime]) VALUES (2, N'IN', CAST(0x0000A1EE0101AAA4 AS DateTime))
INSERT [dbo].[tblEMPLog] ([ID], [EmpID], [Status], [Htime]) VALUES (1, N'IN', CAST(0x0000A1EE0101B2D8 AS DateTime))
INSERT [dbo].[tblEMPLog] ([ID], [EmpID], [Status], [Htime]) VALUES (1, N'OUT', CAST(0x0000A1EE0101F0F4 AS DateTime))
INSERT [dbo].[tblEMPLog] ([ID], [EmpID], [Status], [Htime]) VALUES (2, N'OUT', CAST(0x0000A1EE01023744 AS DateTime))
Now I want to generate a report like
EmpID, InTime, OutTime, TimeSpent
Time Spent is different of Intime and OutTime.
July 17, 2013 at 9:20 am
WOW!!!! Your second post and you nailed the ddl and sample data. Excellent job!!! This takes many people dozens of posts, if they ever actually do it right. The only minor change was I had to remove the ID from the column list on the insert. Having ddl and sample data makes helping so much easier. Thank you for that.
It would be nice if I knew what you expected as output based on your sample data but in this case the result set is small enough it isn't too bad. I think this should get you what you are looking for.
select i.EmpID, i.Htime as InTime, o.Htime as OutTime, DATEDIFF(minute, i.Htime, o.Htime) as MinutesSpent
from tblEMPLog i
outer apply
(
select top 1 *
from tblEMPLog OutPunches
where OutPunches.EmpID = i.EmpID
and Status = 'Out'
and OutPunches.Htime > i.Htime
order by Htime
) o
where i.Status = 'In'
This will return rows when there is no matching 'Out' punch. If you want to eliminate those you can just change the outer apply to a cross apply.
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
July 17, 2013 at 10:56 am
Superb!!!!!
This is Super Excellent and exactly as I expected.
I was almost on the same lines but was not able to reach the result.
Thanks For your help and Support!
July 17, 2013 at 12:21 pm
Glad that worked for you and thanks for letting me know. Come back anytime you need help.
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply