+ Reply to Thread
Results 1 to 7 of 7

Sumproduct #NA error with multiplication coersion

  1. #1
    Registered User
    Join Date
    11-16-2011
    Location
    US,US
    MS-Off Ver
    Excel 2010
    Posts
    2

    Sumproduct #NA error with multiplication coersion

    The following formula works flawlessly:
    =SUMPRODUCT((ShiftSelectValues=Template!B7:O7)*ShiftHours)

    Where shiftselectedvalues and shifthours are A2:A52 and C2:C52 respectively.

    However if I change the matching criteria to use a column range instead of a row range, for example B2:B30, the calculation fails with #NA. With the evaluate formula tool it looks like matching is causes #NA rather then producing a true or false.

    Anyone know why this is happening and how to fix it. Let me know if you need the spreadsheet. Thanks
    Last edited by evilevil_monkey; 11-17-2011 at 09:19 AM.

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Sumproduct #NA error with multiplication coersion

    Try:

    =SUMPRODUCT((ShiftSelectValues=Template!B7:O7)*TRANSPOSE(ShiftHours))

    confirmed with CTRL+SHIFT+ENTER not just ENTER

    You need to transpose the ShiftHours to convert to row entries, ie. semicolon separated values as opposed to comma separated values
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: Sumproduct #NA error with multiplication coersion

    Isn't it the Template!B7:O7 range that you want to make into a column? If so try using this setup

    =SUMPRODUCT(ISNUMBER(MATCH(ShiftSelectValues,Criteria_Range,0))+0,ShiftHours)

    In that version Criteria_Range can be either a single column or a single row, it doesn't matter which

    ....or as long as the values in Criteria_Range don't repeat you can also use this version

    SUMPRODUCT(SUMIF(ShiftSelectValues,Criteria_Range,ShiftHours))
    Audere est facere

  4. #4
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Sumproduct #NA error with multiplication coersion

    I guess someone is looking over my shoulder.

  5. #5
    Registered User
    Join Date
    11-16-2011
    Location
    US,US
    MS-Off Ver
    Excel 2010
    Posts
    2

    Re: Sumproduct #NA error with multiplication coersion

    Quote Originally Posted by NBVC View Post
    Try:

    =SUMPRODUCT((ShiftSelectValues=Template!B7:O7)*TRANSPOSE(ShiftHours))

    confirmed with CTRL+SHIFT+ENTER not just ENTER

    You need to transpose the ShiftHours to convert to row entries, ie. semicolon separated values as opposed to comma separated values
    This did not work, returned #NA still, however i tried transposing both shifthours and shiftselectvalues and the calculation is now working:
    =SUMPRODUCT((TRANSPOSE(ShiftSelectValues)=B3:B30)*TRANSPOSE(ShiftHours))

    Also
    =SUMPRODUCT(ISNUMBER(MATCH(ShiftSelectValues,Criteria_Range,0))+0,ShiftHours)
    works correctly, though I must ask, how does the +0 cause the function to work.

  6. #6
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: Sumproduct #NA error with multiplication coersion

    Quote Originally Posted by evilevil_monkey View Post
    how does the +0 cause the function to work.
    This part

    ISNUMBER(MATCH(ShiftSelectValues,Criteria_Range,0))

    returns an array of TRUE/FALSE values depending on whether there is a match or not. SUMPRODUCT needs to work with numbers so +0 "co-erces" TRUE to 1 and FALSE to 0. You could use "implicit coercion" by multiplying the two conditions like this

    =SUMPRODUCT(ISNUMBER(MATCH(ShiftSelectValues,Criteria_Range,0))*ShiftHours)

    but it's arguably more inefficient that way.....and if ShiftHours contains any text values (even a "null string" "" returned by a formula) that will give you a #VALUE! error - the first version ignores text

  7. #7
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Sumproduct #NA error with multiplication coersion

    As pointed out by daddylonglegs.. I misinterpreted the range transposition you were requesting....

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Tags for this Thread

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1