Consulting

Results 1 to 17 of 17

Thread: SUMPRODUCT (or array formula?) question

  1. #1
    VBAX Tutor Benzadeus's Avatar
    Joined
    Dec 2008
    Location
    Belo Horizonte, Brazil
    Posts
    271
    Location

    SUMPRODUCT (or array formula?) question

    Hi fellows,

    Having trouble trying to make a formula work. Could you help me?
    Attached workbook is simple and self-explanatory.


    *If possible, do not use an auxiliar row to make the desired formula to work.

    Thank you.

  2. #2
    in H12 you can put
    =SUM(VLOOKUP(C$15,$B$6:$C$7,2)*C12,VLOOKUP(D$15,$B$6:$C$7,2)*D12,VLOOKUP(E$15,$B$6:$C$7,2)*E12)
    you can then drag that formula down

    there is probably a way to do this as an array formula but I'm not sure how....

  3. #3
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,443
    Location
    Here's one way

    =SUMPRODUCT(C12:E12,N(OFFSET($C$6,MATCH($C$15:$E$15,$B$6:$B$7,0)-1,0)))
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  4. #4
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,443
    Location
    BTW, that would have been a nice one to put in our new SUMPRODUCT sub-forum
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  5. #5
    Administrator
    VP-Knowledge Base
    VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    I think so too!
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

  6. #6
    VBAX Tutor Benzadeus's Avatar
    Joined
    Dec 2008
    Location
    Belo Horizonte, Brazil
    Posts
    271
    Location
    Thank you guys, and thanks for moving thread.

    I chose xld's formula because my real table is bigger and has a lot of "Quantity" columns.

    xld: why does the formula doesn't work if I take the 'N' function?

  7. #7
    VBAX Tutor Benzadeus's Avatar
    Joined
    Dec 2008
    Location
    Belo Horizonte, Brazil
    Posts
    271
    Location
    One more question:
    Occasionaly, some cell of row 15 will be at blank. If this happens, I get an error from the formula. Is there any way to fix it?
    I tried using IF/ISERROR and also IF/C15:E15<>"" as an array formula with no success.

    Edit: Assume that when that cell in row 15 is blank, the value to multiply the elements in the column is 0.

  8. #8
    Administrator
    VP-Knowledge Base VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    How about a simple workaround; force a substitute if a letter is deleted.
    Last edited by mdmackillop; 04-22-2009 at 04:56 AM. Reason: Error in event code fixed
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

  9. #9
    VBAX Tutor Benzadeus's Avatar
    Joined
    Dec 2008
    Location
    Belo Horizonte, Brazil
    Posts
    271
    Location
    I did it!

    The array formula is:
    =SUMPRODUCT(C12:E12,IF(ISERROR(N(OFFSET($C$6,MATCH($C$15:$E$15,$B$6:$B$7,0)-1,0))),0,N(OFFSET($C$6,MATCH($C$15:$E$15,$B$6:$B$7,0)-1,0))))
    The only bad thing is (I think) that the CPU cost of this formula is higher than if I used a hidden auxiliar row, like rule #9 at this link: http://www.ozgrid.com/forum/showthread.php?t=76234, or like a hidden LOOKUPV at row 16 bringing the desired letter value.

    I got one more challenge... the column at my database where I'm using this formula is filled by merged cells, and Excel does not accept array formulas in merged cells.

  10. #10
    VBAX Tutor Benzadeus's Avatar
    Joined
    Dec 2008
    Location
    Belo Horizonte, Brazil
    Posts
    271
    Location
    I managed to do a better formula than the one above (it's an array formula too):
    =SUMPRODUCT(C12:E12,IF($C$15:$E$15="",0,N(OFFSET($C$6,MATCH($C$15:$E$15,$B$ 6:$B$7,0)-1,0))))

    As for the problem of the merged cells array formula, I noticed that merged cells can have an array formula by doing this:

    1 - Unmerge the cells where you want to put the formula;
    2 - Put the array formula on the single top cell;
    3 - Merge again as desired;
    4 - Copy the formula to the others cells.

  11. #11
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,443
    Location
    If you need to CSE it, there is no point in SUMPRODUCT, you might just as well SUM it

    =SUM((C12:E12)*(IF($C$15:$E$15="",0,N(OFFSET($C$6,MATCH($C$15:$E$15,$B$6:$B$7,0)-1,0)))))
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  12. #12
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,443
    Location
    Quote Originally Posted by Benzadeus
    I got one more challenge... the column at my database where I'm using this formula is filled by merged cells, and Excel does not accept array formulas in merged cells.
    Don't use merged cells, they are more trouble than they are worth.
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  13. #13
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,443
    Location
    Quote Originally Posted by Benzadeus
    xld: why does the formula doesn't work if I take the 'N' function?
    Because OFFSET returns cell references, we need the values, so with use N to force them to values.
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  14. #14
    VBAX Tutor Benzadeus's Avatar
    Joined
    Dec 2008
    Location
    Belo Horizonte, Brazil
    Posts
    271
    Location
    Quote Originally Posted by xld
    Don't use merged cells, they are more trouble than they are worth.
    Could not convince my boss about that.

  15. #15
    VBAX Tutor Benzadeus's Avatar
    Joined
    Dec 2008
    Location
    Belo Horizonte, Brazil
    Posts
    271
    Location
    Quote Originally Posted by xld
    If you need to CSE it, there is no point in SUMPRODUCT, you might just as well SUM it

    =SUM((C12:E12)*(IF($C$15:$E$15="",0,N(OFFSET($C$6,MATCH($C$15:$E$15,$B$6:$B$7,0)-1,0)))))
    I'm sorry, but what is CSE?

    Anyway, thanks for all explanation.

    *Your SUMPRODUCT's www.xldynamic.com/source/xld.SUMPRODUCT.html is offline.

  16. #16
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,443
    Location
    Quote Originally Posted by Benzadeus
    I'm sorry, but what is CSE?

    Anyway, thanks for all explanation.

    *Your SUMPRODUCT's www.xldynamic.com/source/xld.SUMPRODUCT.html is offline.
    CSE is Control-Shift-Enter.
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  17. #17
    Administrator
    VP-Knowledge Base VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    Quote Originally Posted by Benzadeus
    Could not convince my boss about that.
    Using Centre Across Selection usually achieves the same appearance without causing VBA problems. At work, I have reassigned the button to avoid the merged cells situation.
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

Posting Permissions

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