Results 1 to 4 of 4
  1. #1
    vinsavant is offline Novice
    Windows 8 Access 2013
    Join Date
    Dec 2012
    Posts
    20

    Sum After Anniversary Date


    I need to calculate the total number of personal time off hours (PTOs) an employee has taken since his last employment anniversary date. For example, the calculation should take into account the Hire Date of the employee and when was the last anniversary date for this employee and then return the sum of the all the hours taken as of the day of the query by the employee.

    I have a table that store the EmpID, Name, HireDate and a second table the stores NumberOfPTOHours, DateTaken, EmpID, etc.

    Any help would be greatly appreciated.

    Thanks!

  2. #2
    jzwp11 is offline VIP
    Windows 7 64bit Access 2010 64bit
    Join Date
    Jun 2010
    Location
    Dayton, OH
    Posts
    2,901
    You will need to use the hiredate to create the anniversary date. The trick is to pick the correct year for the anniversary date. For example, if we want to run the query today (2/18/2013) and the employee's anniversary date is April 1st, we have to use 4/1/2012 as the anniversary date, but if the anniversary date is February 1st we have to use this year (2/1/2013). So in words, if the anniversary occurs after today, then the anniversary date must use last year's year. If the anniversary occurred before today, then use the current year.

    Since we have a condition, we will need the IIF() function. We will also need the dateserial() function as well as the year(), month(), day(), date() and dateadd() functions

    The following expression calculates the anniversary date relative to the current date:

    IIF(dateserial(year(date()), month(hiredate),day(hiredate))>date(),dateserial(y ear(dateadd("yyyy",-1,date())),month(hiredate),day(hiredate)),dateseri al(year(date()),month(hiredate),day(hiredate)))


    Now in terms of your query, you need to find the dates between the date the query is run (i.e. the current date) and the anniversary date. So in words you want the records BETWEEN today and anniversary date, so the WHERE clause of the query would look like this:


    WHERE datetaken BETWEEN date() AND IIF(dateserial(year(date()), month(hiredate),day(hiredate))>date(),dateserial(y ear(dateadd("yyyy",-1,date())),month(hiredate),day(hiredate)),dateseri al(year(date()),month(hiredate),day(hiredate)))

    The expression in red is just the expression for the anniversary date

  3. #3
    vinsavant is offline Novice
    Windows 8 Access 2013
    Join Date
    Dec 2012
    Posts
    20

    Thanks!

    Thank you so much for your prompt and valuable information. It works great.
    Regards,


    Quote Originally Posted by jzwp11 View Post
    You will need to use the hiredate to create the anniversary date. The trick is to pick the correct year for the anniversary date. For example, if we want to run the query today (2/18/2013) and the employee's anniversary date is April 1st, we have to use 4/1/2012 as the anniversary date, but if the anniversary date is February 1st we have to use this year (2/1/2013). So in words, if the anniversary occurs after today, then the anniversary date must use last year's year. If the anniversary occurred before today, then use the current year.

    Since we have a condition, we will need the IIF() function. We will also need the dateserial() function as well as the year(), month(), day(), date() and dateadd() functions

    The following expression calculates the anniversary date relative to the current date:

    IIF(dateserial(year(date()), month(hiredate),day(hiredate))>date(),dateserial(y ear(dateadd("yyyy",-1,date())),month(hiredate),day(hiredate)),dateseri al(year(date()),month(hiredate),day(hiredate)))


    Now in terms of your query, you need to find the dates between the date the query is run (i.e. the current date) and the anniversary date. So in words you want the records BETWEEN today and anniversary date, so the WHERE clause of the query would look like this:


    WHERE datetaken BETWEEN date() AND IIF(dateserial(year(date()), month(hiredate),day(hiredate))>date(),dateserial(y ear(dateadd("yyyy",-1,date())),month(hiredate),day(hiredate)),dateseri al(year(date()),month(hiredate),day(hiredate)))

    The expression in red is just the expression for the anniversary date

  4. #4
    jzwp11 is offline VIP
    Windows 7 64bit Access 2010 64bit
    Join Date
    Jun 2010
    Location
    Dayton, OH
    Posts
    2,901
    You're welcome

Please reply to this thread with any new information or opinions.

Similar Threads

  1. Replies: 1
    Last Post: 02-12-2013, 03:48 AM
  2. Replies: 5
    Last Post: 12-18-2012, 02:37 PM
  3. Replies: 3
    Last Post: 08-21-2012, 03:05 PM
  4. Replies: 15
    Last Post: 04-06-2012, 10:57 AM
  5. Replies: 3
    Last Post: 04-01-2012, 01:40 PM

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  
Other Forums: Microsoft Office Forums