excel function - 401K contribution calculation

sidel80

New Member
Joined
Jul 15, 2003
Messages
25
Hiya,

I was wondering if anyone can help with this excel function.

I have two columns – A & B. A=employee wage, B=employee contribution. I’m trying to calculate how much 401K the company would match assuming:

- First 3% 100% match
- Next 2% 50% match
- Any employee wage over $200K is limited to just $200K matching.

I was hoping to do this all in one function. Any help? Thanks!
 

Some videos you may like

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.

PA HS Teacher

Well-known Member
Joined
Jul 17, 2004
Messages
2,838
I'm sure it can be done more efficiently with a lookup function, but how about the following for now:

Code:
=MIN(B1,0.03)*IF(A1>=200000,200000,A1)+
  MIN(B1-0.03,0.02)*(B1-0.03>0)* 0.5*IF(A1>200000,200000,A1)
Book1
ABCD
1$250,000.005.0%$8,000.00
2$200,000.005.0%$8,000.00
3$100,000.002.0%$2,000.00
4$100,000.003.0%$3,000.00
5$100,000.004.0%$3,500.00
6$100,000.005.0%$4,000.00
7$100,000.009.0%$4,000.00
Sheet1
 

rrdonutz

Well-known Member
Joined
Jan 15, 2003
Messages
564
Another formula that returns the same results (without a lookup):

=MIN(A1,200000)*(MIN(B1,3%)+MEDIAN(B1-3%,0,2%)/2)
 

Watch MrExcel Video

Forum statistics

Threads
1,122,421
Messages
5,596,033
Members
414,039
Latest member
southike

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