SUMPRODUCT #Value! Error

brncao

Board Regular
Joined
Apr 28, 2015
Messages
147
Hello all,

I'm getting a #Value! error in the column "Result." Does anyone know what's the correct way to fix it? The formula evaluator is showing that the dates are where the error is occurring. I thought if the dates match, result should show 1, if not then 0.
SumProduct Error.xlsx
ABCDEFGHI
1Column1Column2Column3ResultColumn1Column2Column3Extracted Date
21A1/1/2021#VALUE!1ASomeText 01/01/2021 On Text1/1/2021
32B1/2/2021#VALUE!3CSomeText 01/02/2021 On Text1/2/2021
43C1/3/2021#VALUE!4DSomeText 01/04/2021 On Text1/4/2021
54D1/4/2021#VALUE!6FMr. Excel#VALUE!
65E1/5/2021#VALUE!7G#VALUE!
Sheet1
Cell Formulas
RangeFormula
D2:D6D2=SUMPRODUCT(--(Table2[Column1]=[@Column1]),--(Table2[Column2]=[@Column2]),--(Table2[Extracted Date],[@Column3]))
I2:I6I2=DATEVALUE(MID([@Column3],SEARCH(" On ",[@Column3])-10,10))
 

Excel Facts

Excel Can Read to You
Customize Quick Access Toolbar. From All Commands, add Speak Cells or Speak Cells on Enter to QAT. Select cells. Press Speak Cells.
Hi Brncao,

You have two challenges:
  1. If any Extracted Date is #VALUE (as are the last two in your example) then all Table1 Result will return #VALUE.
  2. Your --(Table2[Extracted Date],[@Column3]) should be --(Table2[Extracted Date]=[@Column3])
 
Upvote 0
Oops... However, after applying your fix, it's still showing #Value!. So I added IFERROR to Extracted Date to put "" in its place. That fixed it. Although, I'm curious if SUMPRODUCT can be forced to ignore all the errors and return 0.

Thanks!
 
Upvote 0
Just making those two changes worked OK for me.
I assume you may have many more "Extracted Date" rows and that seems the most likely to give #VALUE so I'd wrap the IFERROR around that field and return a null if no date is found.

Brncao.xlsx
ABCDEFGHI
1Column1Column2Column3ResultColumn1Column2Column3Extracted Date
21A01-Jan-2111ASomeText 01/01/2021 On Text01-Jan-21
32B02-Jan-2103CSomeText 01/02/2021 On Text02-Jan-21
43C03-Jan-2104DSomeText 01/04/2021 On Text04-Jan-21
54D04-Jan-2116FMr. Excel 01/05/2021 On duty05-Jan-21
65E05-Jan-2107GMr. Excel 01/05/2021 On duty05-Jan-21
Sheet1
Cell Formulas
RangeFormula
D2:D6D2=SUMPRODUCT(--(Table2[Column1]=[@Column1]),--(Table2[Column2]=[@Column2]),--(Table2[Extracted Date]=[@Column3]))
I2:I6I2=DATEVALUE(MID([@Column3],SEARCH(" On ",[@Column3])-10,10))
Named Ranges
NameRefers ToCells
Column1=Sheet1!$F$2:$F$6D2:D6
Column2=Sheet1!$G$2:$G$6D2:D6
Column3=Sheet1!$H$2:$H$6I2
Extracted_Date=Sheet1!$I$2:$I$6D2:D6
 
Upvote 0
Thanks. Not all the records in Column3 of Table2 will have the keyword " ON ", which is what I want to ignore. This has now been solved!
 
Upvote 0
OK.
=IFERROR(DATEVALUE(MID([@Column3],SEARCH("/",[@Column3])-2,10)),"")
 
Upvote 0

Forum statistics

Threads
1,213,557
Messages
6,114,291
Members
448,564
Latest member
ED38

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