N/As in Sumproduct

wiscokid

Board Regular
Joined
Aug 2, 2004
Messages
112
I am taking the sumproduct of three columns using the following formula
=SUMPRODUCT(--($M11=Data!$F$2:$F$100),--(Data!$DT$2:$DT$100=N$9),(Data!$I$2:$I$100))

The problem is that if I have any N/A's in either of these three columns (F,DT and I) I get an N/A returned, even if I should be having a value returned.

thanks

Paul
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
Are the N/As the result of formulas?

The best way to handle it is usually to fix the underlying data. If the N/As are the result of formulas, they can be fixed by replacing the offending formula with something like:

=IF(ISNA(formula),0,formula)
 
Upvote 0
The N/As are the result of data downloaded from SQL. No formulas are used in excel for the data
 
Upvote 0
Is it possible to have the problem fixed on the SQL side? SUMPRODUCT formulas and other array formulas really do not like errors in the data.

You could always use the ISNA formula format I displayed above to create formulas to fix the data, and then run your SUMPRODUCT off of this instead.

For example, column F is one of your columns of data. If this is one of the columns with some N/A data, insert a column and use:

=IF(ISNA(F2),0,F2)

If the ISNA function does not recognize the N/A data, then Excel probably sees the N/A as text, and you should be able to simply use the Replace functionality (Edit | Replace) to replace N/A with some other value, like 0 or 1, depending on how you need your formulas to work.
 
Upvote 0
So are the N/As just text or actual error values?

If they're just text then you should be able to use

=SUM(IF(ISNUMBER(Data!$I$2:$I$100),Data!$I$2:$I$100)*($M11=Data!$F$2:$F$100)*(Data!$DT$2:$DT$100=N$9))

confirmed with CTRL+SHIFT+ENTER
 
Upvote 0
I am taking the sumproduct of three columns using the following formula
=SUMPRODUCT(--($M11=Data!$F$2:$F$100),--(Data!$DT$2:$DT$100=N$9),(Data!$I$2:$I$100))

The problem is that if I have any N/A's in either of these three columns (F,DT and I) I get an N/A returned, even if I should be having a value returned.

thanks

Paul

=SUM(IF(ISNUMBER(MATCH(Data!$F$2:$F$100,$M11,0)),IF(ISNUMBER(MATCH(Data!$DT$2:$DT$100,N$9,0)),IF(ISNUMBER(Data!$I$2:$I$100),Data!$I$2:$I$100))))

which you need to confirm with control+shift+enter, not just with enter.
 
Upvote 0

Forum statistics

Threads
1,214,575
Messages
6,120,344
Members
448,956
Latest member
Adamsxl

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