SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


First Absence of the Week in a Monthly Pay Period


First Absence of the Week in a Monthly Pay Period

Author
Message
DiabloSlayer
DiabloSlayer
SSC Veteran
SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)

Group: General Forum Members
Points: 249 Visits: 434
Hello Everyone,

I need some help in creating a SQL query to identify ONLY the first absence of the week in a monthly pay period so when I do my query for an employee for a month I should be able to flag it:

Week starts on Monday
Month is September 2010 (for example sake)

My table is called emp_absence and the columns are as follows:

Emp_No, Absence, AbsenceDate, PayPeriodStartDate, PayPeriodEndDate

Note: Absence column value '0' means no absence and '1' means absence

Example Scenario:

On first week an employee has an absence on Thursday (9/2/2010) and Friday (9/3/2010).
On second week this employee has an absence on Monday (9/6/2010).
On third week no absence.
On fourth week he has an absence on Tuesday (9/21/2010)and Friday (9/24/2010).
On fifth week no absence.

SQL Query

select Emp_No, Absence, AbsenceDate,
CASE Absence
WHEN 0 THEN
No_Absence_In_The_Week'
WHEN 1 THEN
'First_Absence_Of_The_Week'
END Absence_Flag
from emp_absence

where absencedate between PayPeriodStartDate and PayPeriodEndDate
and Absence = '1'

Expected Results:

Emp_No AbsenceDate Absence_Flag
--------------- ----------- ----------------------- -------------------------
Test, Emp 09-02 2010 First_Absence_Of_The_Week
Test, Emp 09-06 2010 First_Absence_Of_The_Week
Test, Emp 09-21 2010 First_Absence_Of_The_Week

Right now when I run this query it picks up all the absences in a week which is incorrect.

I appreciate all the help I can get to have a working query.

Best Regards,

ZA
WayneS
WayneS
SSChampion
SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)

Group: General Forum Members
Points: 12215 Visits: 10602
How's this?

-- See how this starts off with a table and data in it?
-- If you had provided us the data in this format,
-- it would have made things easier for all of the
-- volunteers on this site to help you out.
DECLARE @emp_absence TABLE (
Emp_No INT,
Absence BIT,
AbsenceDate DateTime,
PayPeriodStartDate DateTime,
PayPeriodEndDate DateTime);

INSERT INTO @emp_absence (Emp_No, Absence, AbsenceDate)
SELECT 1, 1, '9/2/2010' UNION ALL
SELECT 1, 1, '9/3/2010' UNION ALL
SELECT 1, 1, '9/6/2010' UNION ALL
SELECT 1, 1, '9/21/2010' UNION ALL
SELECT 1, 1, '9/24/2010';


WITH CTE AS
(
-- get the week #, and row number that starts over at 1 for each change in emp_no or week #
SELECT *,
WeekNo = DATEPART(week, AbsenceDate),
RN = ROW_NUMBER() OVER (PARTITION BY Emp_No, DATEPART(week, AbsenceDate) ORDER BY AbsenceDate)
FROM @emp_absence
)
-- only get the first absence of each week.
SELECT *
FROM CTE
WHERE RN = 1;



Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
If you can't explain to another person how the code that you're copying from the internet works, then DON'T USE IT on a production system! After all, you will be the one supporting it!
Links: For better assistance in answering your questions, How to ask a question, Performance Problems, Common date/time routines,
CROSS-TABS and PIVOT tables Part 1 & Part 2, Using APPLY Part 1 & Part 2, Splitting Delimited Strings

DiabloSlayer
DiabloSlayer
SSC Veteran
SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)

Group: General Forum Members
Points: 249 Visits: 434
Thank you Wayne, I'll give it a go.

Much appreciate it.

Best Regards,

ZA
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search