Sum Product "#VALUE!"

dunmore83

Well-known Member
Joined
Aug 24, 2011
Messages
540
Hi,

This formula works if there are no 0's in the S12:S206 range.

=(SUMPRODUCT((MONTH('F02-Silage-Milkers'!$G$12:$G$206)=$M12)*(YEAR('F02-Silage-Milkers'!$G$12:$G$206)=$J12)*('F02-Silage-Milkers'!$S$12:$S$206))/1000)

However if the formulas in S12:S206 return a 0 value then the above formula returns a "#VALUE!" error.

Can someone please provide a work around?

Thanks
 

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
The formula will cope with a zero in any of the ranges, and will return zero as the result.

What is the formula putting the zero into S12:S206?
Check they are not returning "-" ( a dash to imitate a zero) or returning from an IF formula "0" (zero in quotes) which will return zero as text and cause sumproduct to #value
 
Upvote 0
Try...
Rich (BB code):

=SUMPRODUCT('F02-Silage-Milkers'!$S$12:$S$206,
    (MONTH('F02-Silage-Milkers'!$G$12:$G$206)=$M12)*
    (YEAR('F02-Silage-Milkers'!$G$12:$G$206)=$J12))/1000

Does this resolve the #VALUE! result problem?
 
Upvote 0
That works and it surprises me, Aladin
I just changed my test sheet to =(SUMPRODUCT((MONTH('F02-Silage-Milkers'!$G$12:$G$206)=$M12)*(YEAR('F02-Silage-Milkers'!$G$12:$G$206)=$J12),('F02-Silage-Milkers'!$S$12:$S$206))/1000) and it removed the #Value when I had deliberately put text into S12:S206 range
 
Upvote 0
That works and it surprises me, Aladin
I just changed my test sheet to =(SUMPRODUCT((MONTH('F02-Silage-Milkers'!$G$12:$G$206)=$M12)*(YEAR('F02-Silage-Milkers'!$G$12:$G$206)=$J12),('F02-Silage-Milkers'!$S$12:$S$206))/1000) and it removed the #Value when I had deliberately put text into S12:S206 range

SumProduct, just like Sum, ignores text in the sum range, if its native syntax is followed. That is:

[0] SumProduct(Term, Term, Term, ...)

[1] SumProduct(SumTerm, CoditionalTerm, ConditionalTerm, ...)

[2] SumProduct(SumTerm, CoditionalTerm*ConditionalTerm* ...)

[3] SumProduct(SumTerm*CoditionalTerm*ConditionalTerm* ...)

The OP uses [3] which is the most at variance with [0].

Note that the conditional terms in [1] requires coercion like --(ConditionalTerm) or (ConditionalTerm)+0. Note also that there is notothing to be gained with [3] (or even [2]), 0+(ConditionalTerm), (ConditionalTerm)*1, etc.
 
Upvote 0

Forum statistics

Threads
1,213,567
Messages
6,114,344
Members
448,570
Latest member
rik81h

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