IFANDSUM Questions

JubberB

New Member
Joined
Nov 1, 2019
Messages
39
I have 4 =IF(AND(SUM formulas that all work individually, but I would like to get them all to work in one cell. Can this be done?

Here are the formulas:
=IF(AND(SUM(D3:L3)>9,(SUM(D3:L3)<14),SUM(D3:E3)>0,SUM(F3:G3)>0),"$50","$0")
=IF(AND(SUM(D3:L3)>14,SUM(D3:L3)>0,SUM(F3:G3)>0),"$75","$0")
=IF(AND(SUM(D3:L3)>9,SUM(D3:L3)<14,SUM(H3:L3)>0),"$75","$0")
=IF(AND(SUM(D3:L3)>14,SUM(H3:L3)>0),"$100","$0")
here's the sheet with all the cells so the columns and numbers make sense:

Data 1Data 2DateDateField 1Field 2Field 3Field 4Field 5Field 6Field 7Field 8Field 9 Commission Bonus $50 Bonus $75 Bonus $75 Bonus $100 Bonus Fields Combined
000000000 $ - $0 $0 $0 $0
000000000 $ - $0 $0 $0 $0
000000000 $ - $0 $0 $0 $0
000000000 $ - $0 $0 $0 $0
000000000 $ - $0 $0 $0 $0
Grand TotalN/AN/AN/A000000000 $ - $ - $ - $ - $ -
<colgroup><col width="78" style="width: 58pt; mso-width-source: userset; mso-width-alt: 2759;"> <col width="68" style="width: 51pt; mso-width-source: userset; mso-width-alt: 2417;"> <col width="47" style="width: 35pt; mso-width-source: userset; mso-width-alt: 1678;" span="2"> <col width="46" style="width: 34pt; mso-width-source: userset; mso-width-alt: 1621;" span="9"> <col width="90" style="width: 68pt; mso-width-source: userset; mso-width-alt: 3214;"> <col width="79" style="width: 59pt; mso-width-source: userset; mso-width-alt: 2816;" span="3"> <col width="86" style="width: 65pt; mso-width-source: userset; mso-width-alt: 3072;"> <col width="159" style="width: 119pt; mso-width-source: userset; mso-width-alt: 5660;"> <tbody> </tbody>

Thank you for the help!
JohnB
 
I tried to compress the formula a bit since there are some duplicated comparisons. However, some of the bonuses have overlapping criteria, so you'd still end up with a complicated formula. You might try this:

=MAX(IF(AND(SUM(E2:M2)>=10,SUM(E2:M2)<=14,SUM(E2:F2)>0,SUM(G2:H2)>0),50,0),
IF(AND(SUM(E2:M2)>=15,SUM(E2:F2)>0,SUM(G2:H2)>0),75,0),
IF(AND(SUM(E2:M2)>=10,SUM(E2:M2)<=14,SUM(I2:M2)>0),75,0),
IF(AND(SUM(E2:M2)>=15,SUM(I2:M2)>0),100,0))
 
Upvote 0

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December

Forum statistics

Threads
1,213,484
Messages
6,113,920
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