Calculating IF formula for Tax & NI Deductions..

promoATkt5DOTcom

New Member
Joined
Apr 17, 2019
Messages
1
Hi All,


Any help is appreciated, I've been playing about with this trying to get the formulas right, assuming an IF formula, but not sure how to separate if it requires an answer between a certain range.


For example, I'm trying to write cell formulas so whatever Gross income is entered it works out what level tax and NI contributions, less any voluntary contributions, resulting in net pay.


I'm hitting a wall with the following:


1) Tax Levels Amount
Basic Rate Up to £32,000.00 (20%)
Upper rate £32,000.01 - £150,000.00 (40%)
Additional Rate £150,000.01 upward (45%)

I can see the following for the basic rate tax as:
=If(B8<=E3,B8*F3,B8*F3)
B8 being Taxable Income after deduction of Personal Allowance


But as soon as i try to qualify a range, ie: If Taxable Income above £32k but below £150k deduct 40%


and the same for 45% on anything above £150k


then i need to figure how to assign each tax bracket deduction based on the level of taxable income, IE, under £32k level 1, over £32k but under £150k=level 2 and so on..






2) National Insurance Levels Lower Upper
0% charged between £0.00 and £154.99
12% charged between £155.00 and £827.00
2% charged anything over £827.00


On a similar basis as above, trying to work out how to apply each at the relevant levels.


3)
If i contribute £1 to my workplace pension, then the employer contributes £2, etc.




ALL & Any assistance is Greatly appreciated.


Many Thanks all in Advance..


KJ
 

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
Hello,

You can nest the IF function so that it fulfils multiple criteria, I assume that if a gross income is say £40,000 then the income tax will be 20%(32000) + 40%(40000 - 32000) which results in 6400 + 3200 = £9600

Going on this basis you can also use a SUMPRODUCT formula and set up some tables before hand to assist with the calculations.

For example to work out the National Insurance based on your values and a 40k gross income:
=SUMPRODUCT((40000/52>{0;155;827})*(40000/52-{0;155;827})*({0;0.12;-0.1}))*52
This returns £3832.80 (National insurance paid per annum) take off the *52 at the end if you want it weekly.

Similar logic can be applied to the income tax part, you can set up an array for the bracket values to make it easier so instead of having {0;155;827} you might want B1:B3 (where B1=0, B2=155, B3=827)

I hope this makes sense. Let me know if you need anything else clearing up.

Also it might be worth taking off the pension from the income before hand as that is free from tax(?)
 
Upvote 0
N.B.
1. It is not necessary to use the Named Ranges but it makes the formula easier to read.
The 2a part is just the name of the sheet where I prepared the example.
The 3 SumProduct formulas are all the same; the ranges are just shown differently.







Excel 2010
ABCDEF
1Amount50,000.00BracketsRateRate_Diff
2Tax13,600.00020%20%
313,600.0032,00040%20%
413,600.00150,00045%5%
513,600.00
613,600.00
7
2a
Cell Formulas
RangeFormula
F2=E2-N(E1)
B2=SUMPRODUCT(--(B1>rB),B1-rB,rDiff)
B3=SUMPRODUCT(--(B1>{0;32000;150000}),B1-{0;32000;150000},{0.2;0.2;0.05})
B4=SUMPRODUCT(--(B1>D2:D4),B1-D2:D4,F2:F4)
B5=(B1>0)*B1*0.2+(B1>32000)*(B1-32000)*0.2+(B1>150000)*(B1-150000)*0.05
B6=IF(AND(B1>0,B1<=32000),B1*0.2,IF(AND(B1>32000,B1<=150000),(B1-32000)*0.4+6400,IF(B1>150000,(B1-150000)*0.45+47200)))
Named Ranges
NameRefers ToCells
'2a'!rB='2a'!$D$2:$D$4
'2a'!rDiff='2a'!$F$2:$F$4
 
Last edited:
Upvote 0
posted above post with new Forum tool.

T201904b.xlsm
ABCDEFG
1Amount50,000.00BracketsRateRate_Diff
2Tax13,600.00020%20%6,400.00
313,600.0032,00040%20%7,200.00
413,600.00150,00045%5%0.00
513,600.001.E+3080.00
613,600.00
2a
Cell Formulas
RangeFormula
F2F2=E2-N(E1)
D5D5=9.99999999999999E+307
G2:G5G2=MAX(0,MIN($B$1,D3)-D2)*E2
B2B2=SUMPRODUCT(--(B1>rB),B1-rB,rDiff)
B3B3=SUMPRODUCT(--(B1>{0;32000;150000}),B1-{0;32000;150000},{0.2;0.2;0.05})
B4B4=SUMPRODUCT(--(B1>D2:D4),B1-D2:D4,F2:F4)
B5B5=SUMPRODUCT(--(B1>aB),B1-aB,aR)
B6B6=SUM(G2:G5)
Named Ranges
NameRefers ToCells
'2a'!rB='2a'!$D$2:$D$4B4, B2, G2
'2a'!rDiff='2a'!$F$2:$F$4B4, B2
 
Upvote 0

Forum statistics

Threads
1,213,484
Messages
6,113,927
Members
448,533
Latest member
thietbibeboiwasaco

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