Chris_010101

Board Regular
Joined
Jul 24, 2017
Messages
187
Office Version
  1. 365
Platform
  1. Windows
Hello,

This one has the potential to be quite complicated, as UK holiday law is governed under the Working Time Directive.

I have been trying to make a calculator on Excel which calculates holiday entitlement and can also take into account if someone starts employment part-way through the holiday year - and their holiday must therefore be calculated pro-rata.

Note:
  • Holiday year runs from 01/01 to 31/12
  • Holiday entitlement is 20 days (plus BH) - 28 in total
  • The law states that an employer cannot round down holiday. For example, if 10.24 days remain, this is rounded up to 10.5. Therefore the CIELING function has been used in the "remaining" balance to achieve this (as the company only allows booking in full days or half days).
  • Remaining cell has bank holidays already taken as the Company policy is they are automatically used.
  • Focus of this is the "full entitlement" cell (C7)
My calculator will show the correct figure of 28 days in the "full entitlement" cell (C7) when the holiday year start in cell C1 is 01/01/2023:
Template Holiday Tracker.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXYZAAABACADAEAFAGAHAIAJ
1NAMEHoliday year start01/01/2023Month12345678910111213141516171819202122232425262728293031Total
2Holiday year end31/12/2023January0.0
3Full entitlement28.00February0.0
4Hours worked per week40.00March0.0
5Carry-over0.00April0.0
6Bank holidays used8.00May0.0
7Full entitlement28.00000June0.0
8July0.0
9August0.0
10RemainingSeptember0.0
1120.00DaysOctober0.0
12November0.0
13December0.0
2023
Cell Formulas
RangeFormula
C7C7=SUM(SUM((C3/5)*C4)/52*SUM(C2-C1)/7)/8
B11B11=CEILING(SUM(C7-C6)-SUM(E2:AI13), 0.5)
AJ2:AJ13AJ2=SUM(E2:AI2)
Cells with Data Validation
CellAllowCriteria
E2:AI13Whole numberbetween 0 and 1

Then when changing the "holiday year start" cell for someone who began employment part-way through the holiday year, the sheet should then return 16.5 in the "full entitlement" cell (C7) as per the UK gov calculation: Outcome - Calculate holiday entitlement - GOV.UK - but it returns the incorrect value of 14.46 (14.5)
Template Holiday Tracker.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXYZAAABACADAEAFAGAHAIAJ
1NAMEHoliday year start26/06/2023Month12345678910111213141516171819202122232425262728293031Total
2Holiday year end31/12/2023January0.0
3Full entitlement28.00February0.0
4Hours worked per week40.00March0.0
5Carry-over0.00April0.0
6Bank holidays used3.00May0.0
7Full entitlement14.46154June0.0
8July0.0
9August0.0
10RemainingSeptember0.0
1111.50DaysOctober0.0
12November0.0
13December0.0
2023
Cell Formulas
RangeFormula
C7C7=SUM(SUM((C3/5)*C4)/52*SUM(C2-C1)/7)/8
B11B11=CEILING(SUM(C7-C6)-SUM(E2:AI13), 0.5)
AJ2:AJ13AJ2=SUM(E2:AI2)
Cells with Data Validation
CellAllowCriteria
E2:AI13Whole numberbetween 0 and 1

Never had this situation before. Is it even possible to calculate correctly?

Thanks,
Chris
 

Excel Facts

Excel Wisdom
Using a mouse in Excel is the work equivalent of wearing a lanyard when you first get to college
Maybe they are calculating from the start of the month (or to get 16.5 the last day of the previous month then applying a ceiling of 0.5)

Book1
BC
1Holiday year start26/06/2023
2Holiday year end31/12/2023
3Full entitlement28
4Hours worked per week40
5Carry-over0
6Bank holidays used3
7Full entitlement16.5
8
9
10Remaining
1113.5Days
12
13
Sheet1
Cell Formulas
RangeFormula
C7C7=CEILING(SUM(SUM((C3/5)*C4)/52*SUM(C2-EOMONTH(C1,-1))/7)/8,0.5)
B11B11=CEILING(SUM(C7-C6)-SUM(E2:AI13), 0.5)
 
Upvote 0
Maybe they are calculating from the start of the month (or to get 16.5 the last day of the previous month then applying a ceiling of 0.5)

Book1
BC
1Holiday year start26/06/2023
2Holiday year end31/12/2023
3Full entitlement28
4Hours worked per week40
5Carry-over0
6Bank holidays used3
7Full entitlement16.5
8
9
10Remaining
1113.5Days
12
13
Sheet1
Cell Formulas
RangeFormula
C7C7=CEILING(SUM(SUM((C3/5)*C4)/52*SUM(C2-EOMONTH(C1,-1))/7)/8,0.5)
B11B11=CEILING(SUM(C7-C6)-SUM(E2:AI13), 0.5)
Thanks for your reply,

I tried your formula with EOMONTH but it now results in an incorrect figure of 28.5 when starting on 01/01
Template Holiday Tracker.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXYZAAABACADAEAFAGAHAIAJ
1NAMEHoliday year start01/01/2023Month12345678910111213141516171819202122232425262728293031Total
2Holiday year end31/12/2023January0.0
3Full entitlement28.00February0.0
4Hours worked per week40.00March0.0
5Carry-over0.00April0.0
6Bank holidays used8.00May0.0
7Full entitlement28.50000June0.0
8July0.0
9August0.0
10RemainingSeptember0.0
1120.50DaysOctober0.0
12November0.0
13December0.0
2023
Cell Formulas
RangeFormula
C7C7=CEILING(SUM(SUM((C3/5)*C4)/52*SUM(C2-EOMONTH(C1,-1))/7)/8,0.5)
B11B11=CEILING(SUM(C7-C6)-SUM(E2:AI13), 0.5)
AJ2:AJ13AJ2=SUM(E2:AI2)
Cells with Data Validation
CellAllowCriteria
E2:AI13Whole numberbetween 0 and 1
 
Upvote 0
Then try mround rather than ceiling for C7
 
Upvote 0
Then try mround rather than ceiling for C7
Works for 01/01
Template Holiday Tracker.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXYZAAABACADAEAFAGAHAIAJ
1NAMEHoliday year start01/01/2023Month12345678910111213141516171819202122232425262728293031Total
2Holiday year end31/12/2023January0.0
3Full entitlement28.00February0.0
4Hours worked per week40.00March0.0
5Carry-over0.00April0.0
6Bank holidays used8.00May0.0
7Full entitlement28.00000June0.0
8July0.0
9August0.0
10RemainingSeptember0.0
1120.00DaysOctober0.0
12November0.0
13December0.0
2023
Cell Formulas
RangeFormula
C7C7=MROUND(SUM(SUM((C3/5)*C4)/52*SUM(C2-EOMONTH(C1,-1))/7)/8, 1)
B11B11=CEILING(SUM(C7-C6)-SUM(E2:AI13), 0.5)
AJ2:AJ13AJ2=SUM(E2:AI2)
Cells with Data Validation
CellAllowCriteria
E2:AI13Whole numberbetween 0 and 1

Not for 26/06 (should be 16.5)
Template Holiday Tracker.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXYZAAABACADAEAFAGAHAIAJ
1NAMEHoliday year start26/06/2023Month12345678910111213141516171819202122232425262728293031Total
2Holiday year end31/12/2023January0.0
3Full entitlement28.00February0.0
4Hours worked per week40.00March0.0
5Carry-over0.00April0.0
6Bank holidays used8.00May0.0
7Full entitlement16.00000June0.0
8July0.0
9August0.0
10RemainingSeptember0.0
118.00DaysOctober0.0
12November0.0
13December0.0
2023
Cell Formulas
RangeFormula
C7C7=MROUND(SUM(SUM((C3/5)*C4)/52*SUM(C2-EOMONTH(C1,-1))/7)/8, 1)
B11B11=CEILING(SUM(C7-C6)-SUM(E2:AI13), 0.5)
AJ2:AJ13AJ2=SUM(E2:AI2)
Cells with Data Validation
CellAllowCriteria
E2:AI13Whole numberbetween 0 and 1
 
Upvote 0
I didn't change the 0.5 to 1 when I did it, I just Changed Ceiling to MRound.
Whether it is accurate enough to work for all dates I haven't tested.
 
Upvote 0

Forum statistics

Threads
1,215,097
Messages
6,123,076
Members
449,094
Latest member
mystic19

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
Back
Top