SUMIFS

markpsealy

New Member
Joined
Feb 3, 2024
Messages
4
Office Version
  1. 365
Platform
  1. Windows
I am working with and the Excel Table below and cannot get the SUMIF function to return the correct value. I also tried using the Column Name References, but with no luck.

My goals is to get Column "M" the "Prior Year Salary" column to populate.

New Bonus Model.xlsx
CDEFGHIJKLM
11YearNameGroupDeptRegionSupervisorHire DateSalary TypeSalary Start DateSalary $Prior Year Salary $
122023Kevin1-ManagersAccountingShreveportJamesActual1/1/2023$205,297.00-
132021Scott1-PrincipalsExecutiveDallasDiane6/1/1969Actual1/1/2021$9,000.00-
142022Scott1-PrincipalsExecutiveDallasDiane6/1/1969Actual1/1/2022$10,000.00-
152023Scott1-PrincipalsExecutiveDallasDiane6/1/1969Actual1/1/2023$11,000.00-
162024Scott1-PrincipalsExecutiveDallasDiane6/1/1969Proposed1/1/2024$12,000.00-
172021Mark1-PrincipalsExecutiveShreveportCherie6/1/1981Actual1/1/2021$9,000.00-
182022Mark1-PrincipalsExecutiveShreveportCherie6/1/1981Actual1/1/2022$10,000.00-
192023Mark1-PrincipalsExecutiveShreveportCherie6/1/1981Actual1/1/2023$11,000.00-
202024Mark1-PrincipalsExecutiveShreveportCherie6/1/1981Proposed1/1/2024$12,000.00-
21Total$8,000.00
Sheet1
Cell Formulas
RangeFormula
M12:M20M12=SUMIFS($L$11:$L$21,$D$11:$D$21,D12,$C$11:$C$21,-C12-1)
L21L21=SUBTOTAL(109,[Target Bonus $])
Cells with Data Validation
CellAllowCriteria
J12:J20ListActual,Proposed
 

Excel Facts

What does custom number format of ;;; mean?
Three semi-colons will hide the value in the cell. Although most people use white font instead.
See modified below with no results. Shouldn't M15 = $10,000, etc?

New Bonus Model.xlsx
CDEFGHIJKLM
11YearNameGroupDeptRegionSupervisorHire DateSalary TypeSalary Start DateSalary $Prior Year Salary $
122023Kevin1-ManagersAccountingShreveportJamesActual1/1/2023$205,297.00-
132021Scott1-PrincipalsExecutiveDallasDiane6/1/1969Actual1/1/2021$9,000.00-
142022Scott1-PrincipalsExecutiveDallasDiane6/1/1969Actual1/1/2022$10,000.00-
152023Scott1-PrincipalsExecutiveDallasDiane6/1/1969Actual1/1/2023$11,000.00-
162024Scott1-PrincipalsExecutiveDallasDiane6/1/1969Proposed1/1/2024$12,000.00-
172021Mark1-PrincipalsExecutiveShreveportCherie6/1/1981Actual1/1/2021$9,000.00-
182022Mark1-PrincipalsExecutiveShreveportCherie6/1/1981Actual1/1/2022$10,000.00-
192023Mark1-PrincipalsExecutiveShreveportCherie6/1/1981Actual1/1/2023$11,000.00-
202024Mark1-PrincipalsExecutiveShreveportCherie6/1/1981Proposed1/1/2024$12,000.00-
21Total$8,000.00
Sheet1
Cell Formulas
RangeFormula
M12:M20M12=SUMIFS($L$12:$L$20,$D$12:$D$20,D12,$C$12:$C$20,-C12-1)
L21L21=SUBTOTAL(109,[Target Bonus $])
Cells with Data Validation
CellAllowCriteria
J12:J20ListActual,Proposed
 
Upvote 0
I see now that the last criteria was Negative.

Can this be done using the Column Names?

Thanks.

New Bonus Model.xlsx
CDEFGHIJKLM
11YearNameGroupDeptRegionSupervisorHire DateSalary TypeSalary Start DateSalary $Prior Year Salary $
122023Kevin1-ManagersAccountingShreveportJamesActual1/1/2023$205,297.00$0.00
132021Scott1-PrincipalsExecutiveDallasDiane6/1/1969Actual1/1/2021$9,000.00$0.00
142022Scott1-PrincipalsExecutiveDallasDiane6/1/1969Actual1/1/2022$10,000.00$9,000.00
152023Scott1-PrincipalsExecutiveDallasDiane6/1/1969Actual1/1/2023$11,000.00$10,000.00
162024Scott1-PrincipalsExecutiveDallasDiane6/1/1969Proposed1/1/2024$12,000.00$11,000.00
172021Mark1-PrincipalsExecutiveShreveportCherie6/1/1981Actual1/1/2021$9,000.00$0.00
182022Mark1-PrincipalsExecutiveShreveportCherie6/1/1981Actual1/1/2022$10,000.00$9,000.00
192023Mark1-PrincipalsExecutiveShreveportCherie6/1/1981Actual1/1/2023$11,000.00$10,000.00
202024Mark1-PrincipalsExecutiveShreveportCherie6/1/1981Proposed1/1/2024$12,000.00$11,000.00
21Total$8,000.00$0.00
Sheet1
Cell Formulas
RangeFormula
M12:M21M12=IF(SUMIFS($L$12:$L$20,$D$12:$D$20,D12,$C$12:$C$20,C12-1)>0,SUMIFS($L$12:$L$20,$D$12:$D$20,D12,$C$12:$C$20,C12-1),0)
L21L21=SUBTOTAL(109,Sheet1!$Q$12:$Q$20)
Cells with Data Validation
CellAllowCriteria
J12:J20ListActual,Proposed
 
Upvote 0
See modified below with no results. Shouldn't M15 = $10,000, etc?
You are using wrong formula

Use exactly as given in #2 without modifying it...

I don't know why you are using
-C12-1
which is wrong

It should be C12-1

Use this without modifying -

Excel Formula:
=SUMIFS($L$12:$L$20,$D$12:$D$20,D12,$C$12:$C$20,C12-1)
 
Upvote 0
=IF(SUMIFS($L$12:$L$20,$D$12:$D$20,D12,$C$12:$C$20,C12-1)>0,SUMIFS($L$12:$L$20,$D$12:$D$20,D12,$C$12:$C$20,C12-1),0)
If you want to use above better use as below -

Excel Formula:
=Let(PYS,SUMIFS($L$12:$L$20,$D$12:$D$20,D12,$C$12:$C$20,C12-1),If(PYS>0,PYS,0))

It's short and crisp.
 
Upvote 0
How about just filtering for the same name for the prior year:


Book1
CDEFGHIJKLM
1YearNameGroupDeptRegionSupervisorHire DateSalary TypeSalary Start DateSalary $Prior Year Salary $
22023Kevin1-ManagersAccountingShreveportJamesActual1/1/2023205,297 
32021Scott1-PrincipalsExecutiveDallasDiane25355Actual1/1/20219,000 
42022Scott1-PrincipalsExecutiveDallasDiane25355Actual1/1/202210,0009,000
52023Scott1-PrincipalsExecutiveDallasDiane25355Actual1/1/202311,00010,000
62024Scott1-PrincipalsExecutiveDallasDiane25355Proposed1/1/202412,00011,000
72021Mark1-PrincipalsExecutiveShreveportCherie29738Actual1/1/20219,000 
82022Mark1-PrincipalsExecutiveShreveportCherie29738Actual1/1/202210,0009,000
92023Mark1-PrincipalsExecutiveShreveportCherie29738Actual1/1/202311,00010,000
102024Mark1-PrincipalsExecutiveShreveportCherie29738Proposed1/1/202412,00011,000
11Total60,000
Sheet2
Cell Formulas
RangeFormula
M2:M10M2=FILTER([Salary $],[Salary Start Date]=EDATE([@[Salary Start Date]],-12)*([Name]=[@Name]),"")
M11M11=SUBTOTAL(109,[Prior Year Salary $])
 
Last edited:
Upvote 0
Whay do I get this error?

1707056675276.png
 
Upvote 0
I think the word "NAME" may be a reserved word in excel. Change it to FNAME, and see if it helps.
 
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