Vacation Hours Accrual calculation

bobbysmith

New Member
Joined
Jan 24, 2015
Messages
29
hey guys,


i was wondering if anyone can help with some vacation accrue calculation. I've search thru threads here for some help but failed to find one that i can duplicate. So basically this is what i need calculated. Any employee that has work between 1-3yrs with the company accrues 8hrs of vacation per month at the end of the month, ie 30 or 31st whatever the case may be. So after 3yrs on their anniversary date (hiredate), they will automatically accrue 12hours/month. For example: 3yrs = 288 hours and then 3yrs and one month = 300hrs and accrue an additional 12hours everymonth until the 10yr mark and then they would start accrueing 16hours/month. i tried using the DATEDIF() and was successful but once its over 3yrs then i've come to a crosspoint. would appreciate any input thanks in advance.


1-3yrs Service 3-9yrs Service 10+yrs Service
8hrs/mnth 12hrs/mnth 16hr/mnth


hiredate currentdate Vaca Accrue
10/10/16 11/30/19 300hrs
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.

CyrusTheVirus

Well-known Member
Joined
Jan 28, 2015
Messages
744
Office Version
  1. 365
Platform
  1. Windows
The immediate question to ask is do you have a payroll system that keeps track of this for you?

Are you really planning on keeping track of this in a spreadsheet?
 
Upvote 0

Dave Patton

Well-known Member
Joined
Feb 15, 2002
Messages
5,746
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
=DATEDIF(B2-1,C2,"m")*8+(MAX(0,(DATEDIF(B2-1,C2,"m")-(3*12))*(12-8)))+(MAX(0,(DATEDIF(B2-1,C2,"m")-(9*12))*(16-12)))

You could put the month calculation in a distinct column.


Excel 2010
BCDEFG
1Start DateCurrent DateMonthsAccrualVac UsedBalance
210-Oct-1630-Nov-19300.002298.00
310-Oct-1630-Nov-1937300.002298.00
3dd
Cell Formulas
RangeFormula
E2=DATEDIF(B2-1,C2,"m")*8+(MAX(0,(DATEDIF(B2-1,C2,"m")-3*12)*(12-8)))+(MAX(0,(DATEDIF(B2-1,C2,"m")-9*12)*(16-12)))
E3=D3*8+(MAX(0,(D3-3*12)*(12-8)))+(MAX(0,(D3-9*12)*(16-12)))
D3=DATEDIF(B3-1,C3,"m")
G2=E2-F2
G3=E3-F3
 
Last edited:
Upvote 0

Forum statistics

Threads
1,191,031
Messages
5,984,235
Members
439,879
Latest member
KingGoulash

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top