+ Reply to Thread
Results 1 to 6 of 6

SUM of VLOOKUP*ARRAY gives different answer when used as single cell

  1. #1
    Registered User
    Join Date
    08-19-2019
    Location
    Netherlands
    MS-Off Ver
    2016
    Posts
    3

    SUM of VLOOKUP*ARRAY gives different answer when used as single cell

    Hi all,

    How can I get the result of this multi cell array formula in a single cell?
    Please Login or Register  to view this content.
    That formula gives different results when used as either single cell or multi cell. To discuss the formula I abbreviate it like this:
    Please Login or Register  to view this content.
    The result of a single cell is that the first value returned by the VLOOKUP (V) is multiplied with the sum or the ARRAY (A). The result I want is what you get when you run the formula in multiple cells: it multiplies the first value returned by V with the first value of A, the second with the second, and so forth. In short:
    Single cell result: V1 * SUM(A)
    multi cell result: V1*A1 + V2*A2 + V3*A3

    Example:
    data (A2:B5)
    atom mass
    hydrogen 1
    carbon 12
    oxygen 16
    chlorine 35

    molecule (A8:B10)
    atom amount
    carbon 2
    hydrogen 6
    oxygen 1

    Use the given formula in any single cell and it will display 108 (9 x 12). Select two or more cells before entering this formula with [ctrl + shift + enter] and it gives 46. That is what I want.

    Cor

  2. #2
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: SUM of VLOOKUP*ARRAY gives different answer when used as single cell

    Hi,

    The required single-cell array formula using VLOOKUP requires a little coercion:

    =SUM(VLOOKUP(T(IF({1},$A$8:$A$10)),$A$2:$B$5,2,0)*$B$8:$B$10)

    More appropriate is the simple:

    =SUM(SUMIF($A$2:$B$5,$A$8:$A$10,$B$2:$B$5)*$B$8:$B$10)

    again with CSE, or:

    =SUMPRODUCT(SUMIF($A$2:$B$5,$A$8:$A$10,$B$2:$B$5)*$B$8:$B$10)

    without CSE.

    Regards
    Click * below if this answer helped

    Advanced Excel Techniques: http://excelxor.com/

  3. #3
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,023

    Re: SUM of VLOOKUP*ARRAY gives different answer when used as single cell

    Try this array formula:

    =SUMPRODUCT(--($A$8:$A$10=TRANSPOSE($A$2:$A$5))*$B$8:$B$10*TRANSPOSE($B$2:$B$5))

    You may need ; instead of ,

    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...
    Attached Files Attached Files
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  4. #4
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,023

    Re: SUM of VLOOKUP*ARRAY gives different answer when used as single cell

    Go with XOR LX's 3rd solution, not mine!!

  5. #5
    Registered User
    Join Date
    08-19-2019
    Location
    Netherlands
    MS-Off Ver
    2016
    Posts
    3

    Re: SUM of VLOOKUP*ARRAY gives different answer when used as single cell

    Wow, such a fast reply. Thank you so much XOR LX and Glenn!

    All three of your suggestions work, also in the real sheet I'm using.
    So, it seems in my formula the search values had to be converted to text values using an IF statement (didn't work without that).
    I couldn't have guessed, thanks! I'll be using the last formula given by XOR.

  6. #6
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,023

    Re: SUM of VLOOKUP*ARRAY gives different answer when used as single cell

    Wise decision!!

    You're welcome.



    If that takes care of your original question, please select "Thread Tools" from the menu link above and mark this thread as SOLVED.

    It'd also be appreciated if you were to click the Add Reputation button at the foot of any of the posts of all members who helped you reach a solution.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. IF with Vlookup and OR? Multiple Lookup Value with Single Array
    By kelvin156 in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 02-09-2018, 08:19 AM
  2. [SOLVED] Max Value Answer In A Range To A Single Cell VBA
    By rmccain in forum Excel Programming / VBA / Macros
    Replies: 4
    Last Post: 07-22-2016, 07:42 PM
  3. [SOLVED] vLookup multiple values separated by ";" in single cell / return result in single cell
    By Tunesmith in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 09-07-2015, 12:02 PM
  4. [SOLVED] Vlookup table array matching with multiple value in single cell separated by comma.
    By kannoy in forum Excel Formulas & Functions
    Replies: 15
    Last Post: 03-04-2015, 04:03 AM
  5. [SOLVED] Return an answer from a column; using an array and a single row ...
    By wesrockin in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 06-28-2013, 03:21 AM
  6. [SOLVED] vlookup answer in different cell
    By Psychlogic in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 01-24-2006, 05:45 PM
  7. [SOLVED] Using single cell reference as table array argument in Vlookup
    By CornNiblet in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 09-22-2005, 04:15 AM

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