Results 1 to 11 of 11
  1. #1
    5 Star Lounger
    Join Date
    Aug 2001
    Location
    Surrey, United Kingdom
    Posts
    1,001
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Calculating accrued holiday (2003 SP2)

    Good morning

    I am trying to devise a formula to calculate how much holiday new starters are due. I have tried to use some nested if formulas but have got nowehere fast. If anyone has a moment could they please take a look at the attached example workbook which will hopefully explain what I am after.

    Thanks

    Cheers

    Steve
    Attached Files Attached Files
    Cheers

    Steve

    Asking the questions everbody wants the answers too but feels too stupid to ask themselves :-)

  2. #2
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts

    Re: Calculating accrued holiday (2003 SP2)

    Should the accrued holidays be calculated using the date boundaries in your worksheet, or as a continuous fraction of the yearly entitlement?

    Should it be rounded to whole days or half days or hours? If so, rund up, down or to the nearest?

  3. #3
    5 Star Lounger
    Join Date
    Aug 2001
    Location
    Surrey, United Kingdom
    Posts
    1,001
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: Calculating accrued holiday (2003 SP2)

    Hi Hans

    If they could be calculated in the date boundaries it would be good and days rounded up/down to nearest would be fantastic

    Cheers

    Steve
    Cheers

    Steve

    Asking the questions everbody wants the answers too but feels too stupid to ask themselves :-)

  4. #4
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts

    Re: Calculating accrued holiday (2003 SP2)

    Try this formula in F4:

    =ROUND(E4*(12-MONTH(C4)+(DAY(C4)<16))/12,0)

  5. #5
    5 Star Lounger
    Join Date
    Aug 2001
    Location
    Surrey, United Kingdom
    Posts
    1,001
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: Calculating accrued holiday (2003 SP2)

    Thanks Hans

    Thats fantastic I don't think I will ever be able to get my head around the logic like that

    Cheers

    Steve
    Cheers

    Steve

    Asking the questions everbody wants the answers too but feels too stupid to ask themselves :-)

  6. #6
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts

    Re: Calculating accrued holiday (2003 SP2)

    I started by creating intermediate formulas, then combined them into one formula.

    MONTH(C4) is the month number of the start date, e.g. for 23 February it is 2.
    12-MONTH(C4) is the number of remaining months in the year, e.g. for 23 February this is 12 - 2 = 10.
    If the date is before the 16th of the month, we add 1 to this: if the start date is 8 February, we count 11 months.
    This is done by adding (DAY(C4)<16) which evaluates to TRUE = 1 before the 16th and to FALSE = 0 on or after the 16th.
    The resulting number is divided by 12 to get the fraction of the year, e.g. for 23 Februari it is 10/12 part of the year.
    This is multiplied by the yearly holidays, and finally the result is rounded to the nearest whole number

  7. #7
    5 Star Lounger
    Join Date
    Aug 2001
    Location
    Surrey, United Kingdom
    Posts
    1,001
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: Calculating accrued holiday (2003 SP2)

    Hi Hans

    The powers to be have now asked that it shows half days, I thought that by removing the round part of the formula it would show the half days but it does not. Sorry to be a pain but how can I change it to the nearest up or down whole number.

    Thanks for your help (and patience)

    Cheers

    Steve
    Cheers

    Steve

    Asking the questions everbody wants the answers too but feels too stupid to ask themselves :-)

  8. #8
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts

    Re: Calculating accrued holiday (2003 SP2)

    > how can I change it to the nearest up or down whole number.

    That's what the formula does now. Did you mean "how can I change it to round to the nearest multiple of 0.5?"

  9. #9
    5 Star Lounger
    Join Date
    Aug 2001
    Location
    Surrey, United Kingdom
    Posts
    1,001
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: Calculating accrued holiday (2003 SP2)

    <img src=/S/blush.gif border=0 alt=blush width=15 height=15> Memo to self, read postings before pushing send <img src=/S/grin.gif border=0 alt=grin width=15 height=15>

    Hi Hans

    Yes, I am sorry, I need to show the half days

    Cheers

    Steve
    Cheers

    Steve

    Asking the questions everbody wants the answers too but feels too stupid to ask themselves :-)

  10. #10
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts

    Re: Calculating accrued holiday (2003 SP2)

    Try

    =ROUND(E4*(12-MONTH(C4)+(DAY(C4)<16))/6,0)/2

    The formula divides by 6 instead of 12, rounds this to a whole number, then divides by 2.

    For example, for start = 20 January and yearly days = 20, E4*(12-MONTH(C4)+(DAY(C4)<16)) evaluates to 20 * 11 = 220.
    The original calculation divided this by 12, resulting in 18.3333... then rounded to 18.
    The new calculation divides by 6, resulting in 36.6666..., rounds to 37, then divides by 2, with end result 18.5.

  11. #11
    5 Star Lounger
    Join Date
    Aug 2001
    Location
    Surrey, United Kingdom
    Posts
    1,001
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: Calculating accrued holiday (2003 SP2)

    Thanks again Hans

    Cheers

    Steve
    Cheers

    Steve

    Asking the questions everbody wants the answers too but feels too stupid to ask themselves :-)

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •