SUMPRODUCT formula that adjusts the bottom of the range but maintains the top of the range

jeffmoseler

Well-known Member
Joined
Jul 16, 2004
Messages
540
I have the following formula in a cell:

=SUMPRODUCT(--(MONTH(Prospects!$AO$12:$AO12)=B1),--(YEAR(Prospects!$AO$12:$AO12)=$A$8),Prospects!$AQ$12:$AQ12)

When I add a row at line 12, it changes the formula to read:

=SUMPRODUCT(--(MONTH(Prospects!$AO$13:$AO13)=B1),--(YEAR(Prospects!$AO$13:$AO13)=$A$8),Prospects!$AQ$13:$AQ13)

How do I write this so that Row 12 stays at 12 and the bottom row grows as I add them. So it should read:

=SUMPRODUCT(--(MONTH(Prospects!$AO$12:$AO13)=B1),--(YEAR(Prospects!$AO$12:$AO13)=$A$8),Prospects!$AQ$12:$AQ13)
 

Excel Facts

How to calculate loan payments in Excel?
Use the PMT function: =PMT(5%/12,60,-25000) is for a $25,000 loan, 5% annual interest, 60 month loan.
Hi Mose

Just changing the syntax of your formula, try:

=SUMPRODUCT(--(MONTH(INDEX(Prospects!$AO:$AO,12):Prospects!$AO13)=B1),--(YEAR(INDEX(Prospects!$AO:$AO,12):Prospects!$AO13)=$A$8),INDEX(Prospects!$AQ:$AQ,12):Prospects!$AQ13)
 
Upvote 0
Thanks! Worked great! I knew there was a way to incorporate the INDEX function but I couldn't wrap my head around how to do it.
 
Upvote 0
This worked great, so I would like to reopen it to ask another question. I would like to apply the same formula to calculate another metric. It needs to have one more condition than the previous one. I thought I could figure it out but once again it is stumping me. Here is what I have:

{=SUMPRODUCT(--((INDEX(Completed!$AS:$AS,2):Completed!$AS6)="Sold"), --(MONTH(INDEX(Completed!$AO:$AO,2):Completed!$AO6)=B1),--(YEAR(INDEX(Completed!$AO:$AO,2):Completed!$AO6)=$A$8),INDEX(Completed!$AQ:$AQ,2):Completed!$AQ6)}

I added the "Sold" condition for another column. It's showing a result of $0 even though the result should be $2,241.30

Can someone evaluate this and let me know if I am writing something incorrectly?
 
Upvote 0
Hi

I don't see anything wrong with the formula.

I would debug it evaluating the conditions one by one to see which is not working.

For ex., the condition you added:

=SUMPRODUCT(--((INDEX(Completed!$AS:$AS,2):Completed!$AS6)="Sold"))

Does this work how you expect?
 
Upvote 0

Forum statistics

Threads
1,213,535
Messages
6,114,194
Members
448,554
Latest member
Gleisner2

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