#VALUE! error

exceluserkt

New Member
Joined
Nov 16, 2009
Messages
3
I have a table that contains SUMPRODUCT functions. It compares text values and then sums a corresponding number value. It was working fine until I upgraded to 2007 and now when I hit F9(Calculate), all the cells go to #VALUE! and I can't get the actual number values back. How do I get the values back?

Multiple people in my office rely on this sheet so please help
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number

Scott Huish

MrExcel MVP
Joined
Mar 17, 2004
Messages
19,958
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
What is your formula? Do you have #VALUE! errors anywhere in your data range?
 

exceluserkt

New Member
Joined
Nov 16, 2009
Messages
3
The first formula in the table is

=SUMPRODUCT(--(LaborHours!$A$6:$A$4999=$A3),--(LaborHours!$D$6:$D$4999=J$2),--(LaborHours!$E$6:$E$4999))

Column A is a project number(text) column D is a category (text) and E is the number of hours to sum. The sheet where the numbers are summed does not contai any errors. This problem only occured when I upgraded to 2007 and hit F9(calculate). It had been working flawlessly for two months.
 

Scott Huish

MrExcel MVP
Joined
Mar 17, 2004
Messages
19,958
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
That formula should still work. Although you don't need the -- and the parentheses around the last part.


Put this formula in a blank cell on the same sheet where you have that formula:

=SUMPRODUCT(--(ISERROR(LaborHours!A6:A4999)))+SUMPRODUCT(--(ISERROR(LaborHours!$D$6:$D$4999)))+SUMPRODUCT(--(ISERROR(LaborHours!$E$6:$E$4999)))+ISERROR(A3)+ISERROR(J2)

What does it return?

If that returns 0, is there any text in E6:E4999 on the LaborHours sheet?
 
Last edited:

exceluserkt

New Member
Joined
Nov 16, 2009
Messages
3
You were right. I found that someone entered a " . " in that column instead of " 0 "

Thanks for your help
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,209
You were right. I found that someone entered a " . " in that column instead of " 0 "

Thanks for your help

If such is in the range to sum, the native syntax would cope with that...
Code:
=SUMPRODUCT(
   --(LaborHours!$A$6:$A$4999=$A3),
   --(LaborHours!$D$6:$D$4999=J$2),
  LaborHours!$E$6:$E$4999)
 

Forum statistics

Threads
1,136,639
Messages
5,676,935
Members
419,660
Latest member
Fred Cailloux

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
Top