SUMIF - two criteria wont sum between two date ranges

twilliamsli

New Member
Joined
Feb 22, 2019
Messages
8
I am attempting to sum payments on one tab and return the sum to another tab. The payments are identified by a unique identifier - a loan number. The are multiple payments per loan, and hundreds of loans.

My original formula works - that is to sum all payments from (after) one date: =SUMIFS(Payments!Q:Q,Payments!A:A,@'Legal vs Payments'!A:A,Payments!G:G,">"&J4).
(in summary, sum all the payments found in Column Q on the "payments tab" if all the loan numbers in Columns A, on the Payments and Legal Payments tab match, sum all after date found in Column J)
The problem is when I add an end date to the formula - it returns a $0.00 or #name? error. I have tried two ways:
first method =SUMIFS(Payments!Q:Q,Payments!A:A,@'Legal vs Payments'!A:A,Payments!A:A,">="&E4, dates, "<="&F4) - this returns a #name? error
the second method - =SUMIFS(Payments!Q:Q,Payments!A:A,@'Legal vs Payments'!A:A,Payments!A:A,">="&E5,Payments!Q:Q,"<="&F5) - this returns a $0.00 return.

I thought it might be a simple typo - I think it is more of a formula layout, that I am not seeing.

any assistance you can offer would be greatly appreciated........
 

Excel Facts

Links? Where??
If Excel says you have links but you can't find them, go to Formulas, Name Manager. Look for old links to dead workbooks & delete.
Bit confusing as your cells seem to change, but maybe
Excel Formula:
=SUMIFS(Payments!Q:Q,Payments!A:A,@'Legal vs Payments'!A:A,Payments!G:G,">="&E5,Payments!G:G,"<="&F5)
 
Upvote 0
Solution
Highlighting your errors so you can see where you went wrong.

In the first formula, the #NAME? error tells us that a name used in the formula doesn't exist, comparing it to your working formula, it can only be dates which implies a non existent named range.

=SUMIFS(Payments!Q:Q,Payments!A:A,@'Legal vs Payments'!A:A,Payments!A:A,">="&E4, dates, "<="&F4)

In the second formula, you have applied the new date criteria to the sum column instead of the criteria column.

=SUMIFS(Payments!Q:Q,Payments!A:A,@'Legal vs Payments'!A:A,Payments!A:A,">="&E5,Payments!Q:Q,"<="&F5)

Changing that to the correct column for the dates should work.

=SUMIFS(Payments!Q:Q,Payments!A:A,@'Legal vs Payments'!A:A,Payments!A:A,">="&E4,Payments!A:A, "<="&F4)

Although, I think that @Fluff's suggestion above might be more accurate, there appear to be too many criteria pointing to the same column in your formula but the reference to column G in the first was something that I missed.
 
Upvote 0
Bit confusing as your cells seem to change, but maybe
Excel Formula:
=SUMIFS(Payments!Q:Q,Payments!A:A,@'Legal vs Payments'!A:A,Payments!G:G,">="&E5,Payments!G:G,"<="&F5)
Thank you, this worked perfectly. I did not realize the payments were in multiple places in the data. Thank you
 
Upvote 0
Glad we could help & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,651
Messages
6,120,744
Members
448,989
Latest member
mariah3

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