+ Reply to Thread
Results 1 to 8 of 8

Sum with multiple criteria no. 2

  1. #1
    Forum Contributor
    Join Date
    04-14-2012
    Location
    Melbourne
    MS-Off Ver
    Excel 2007
    Posts
    133

    Sum with multiple criteria no. 2

    i have a group of assets and liabilities.
    first they need to go pass 2 conditions, they are

    day assets, and green assets.
    then, in those
    there are different securities such as
    ax
    ay
    bx
    by
    cx
    cy

    we need to ignore the last letter.
    sum all the a, b, c individually.
    add the positive figures and negatives separately.
    Attached Files Attached Files

  2. #2
    Forum Contributor
    Join Date
    04-14-2012
    Location
    Melbourne
    MS-Off Ver
    Excel 2007
    Posts
    133

    Re: Sum with multiple criteria no. 2

    =SUMPRODUCT((SUMIFS(C2:C10,D2:D10,LEFT(D2:D10&" ",LEN(D2)-1)&"*",A2:A10,"Green",B2:B10,"Day")/COUNTIFS(D2:D10,LEFT(D2:D10&"",LEN(D2))&"*")>0)*SUMIFS(C2:C10,D2:D10,LEFT(D2:D10&" ",LEN(D2))&"*",A2:A10,"Green",B2:B10,"Day")/COUNTIFS(D2:D10,LEFT(D2:D10&"",LEN(D2))&"*"))

    i have added extra condition, is this correct? results seem right.

  3. #3
    Forum Guru benishiryo's Avatar
    Join Date
    03-25-2011
    Location
    Singapore
    MS-Off Ver
    Excel 2013
    Posts
    5,147

    Re: Sum with multiple criteria no. 2

    hi there. good that do you uploaded a excel sample

    but do input the desired results so that we don't have to second-guess if what we are doing is correct or not. you may look at my signature to upload an eg that is easier to understand. you gave a solution from online, but is it working like how you want it to?

    if i really guessed it wrongly, please upload something according to my recommendations. try to use the solution i have given and we'll help to advise what went wrong. my guess for positives (C2+C5:C7):
    =SUM(SUMIFS(C:C,A:A,"Green",B:B,"Day",C:C,">0",D:D,{"a*","b*","c*","d*"}))

    and negatives (C3:C4):
    =SUM(SUMIFS(C:C,A:A,"Green",B:B,"Day",C:C,"<0",D:D,{"a*","b*","c*","d*"}))

    saw your 2nd post. why should the answer be 7 and not 9?

    Thanks, if you have clicked on the * and added our rep.

    If you're satisfied with the answer, click Thread Tools above your first post, select "Mark your thread as Solved".

    "Contentment is not the fulfillment of what you want, but the realization of what you already have."


    Tips & Tutorials I Compiled | How to Get Quick & Good Answers

  4. #4
    Forum Guru samba_ravi's Avatar
    Join Date
    07-26-2011
    Location
    Hyderabad, India
    MS-Off Ver
    Excel 2021
    Posts
    8,904

    Re: Sum with multiple criteria no. 2

    G2
    Please Login or Register  to view this content.
    G3
    Please Login or Register  to view this content.
    Try above array formulas

    ...confirmed by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. You will know the array is active when you see curly braces { } appear around your formula. If you do not CTRL+SHIFT+ENTER you will get an error or a clearly incorrect answer.
    Samba

    Say thanks to those who have helped you by clicking Add Reputation star.

  5. #5
    Forum Contributor
    Join Date
    04-14-2012
    Location
    Melbourne
    MS-Off Ver
    Excel 2007
    Posts
    133

    Re: Sum with multiple criteria no. 2

    assuming that I will always have 8 letter code, removing the last letter.

    can I change your formula from
    LEFT(P:P&"",LEN(P7)-1)&"*"
    to
    LEFT(P:P,7)&"*"

    also why do you also have
    LEFT(P:P&"",LEN(P7))&"*"

  6. #6
    Forum Guru samba_ravi's Avatar
    Join Date
    07-26-2011
    Location
    Hyderabad, India
    MS-Off Ver
    Excel 2021
    Posts
    8,904

    Re: Sum with multiple criteria no. 2

    LEFT(P:P,7)&"*"
    You can use this if you don't have any blank cells in your selection -(range you selected in column p)
    If there is any blank cells it counts or sum entire selected range
    It is not a good idea to select the entire range. Please specify the range.

  7. #7
    Forum Contributor
    Join Date
    04-14-2012
    Location
    Melbourne
    MS-Off Ver
    Excel 2007
    Posts
    133

    Re: Sum with multiple criteria no. 2

    why do you sometimes use
    LEFT(P:P&"",LEN(P7)-1)&"*"
    and sometimes use
    LEFT(P:P&"",LEN(P7))&"*"

  8. #8
    Forum Guru samba_ravi's Avatar
    Join Date
    07-26-2011
    Location
    Hyderabad, India
    MS-Off Ver
    Excel 2021
    Posts
    8,904

    Re: Sum with multiple criteria no. 2

    That was my mistake actually it should be LEFT(P:P&" ",LEN(P7)-1)&"*"
    further simplified the formula the below is the one
    for assets
    =SUMPRODUCT((IFERROR((SUMIFS($C$2:$C$10,$A$2:$A$10,"Green",$B$2:$B$10,"Day",$D$2:$D$10,LEFT($D$2:$D$10&" ",LEN($D$2)-1)&"*")/COUNTIFS($A$2:$A$10,"Green",$B$2:$B$10,"Day",$D$2:$D$10,LEFT($D$2:$D$10&" ",LEN($D$2)-1)&"*")),0)>0)*(C$2:C$10))
    for liabilies
    =SUMPRODUCT((IFERROR((SUMIFS($C$2:$C$10,$A$2:$A$10,"Green",$B$2:$B$10,"Day",$D$2:$D$10,LEFT($D$2:$D$10&" ",LEN($D$2)-1)&"*")/COUNTIFS($A$2:$A$10,"Green",$B$2:$B$10,"Day",$D$2:$D$10,LEFT($D$2:$D$10&" ",LEN($D$2)-1)&"*")),0)<0)*(C$2:C$10))

+ 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. [SOLVED] Counting cells that meet multiple single criteria as variable criteria
    By BillBasil in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 02-01-2016, 10:33 AM
  2. Replies: 9
    Last Post: 07-23-2015, 01:21 PM
  3. Replies: 2
    Last Post: 05-26-2015, 07:29 PM
  4. [SOLVED] countifs statement with multiple criteria for multiple criteria ranges
    By mcdermott2 in forum Excel Formulas & Functions
    Replies: 9
    Last Post: 05-07-2015, 11:48 AM
  5. [SOLVED] UDF for sum of multiple criteria in multiple columns and single criteria in multiple colum
    By Ganesh7299 in forum Excel Programming / VBA / Macros
    Replies: 32
    Last Post: 11-22-2013, 04:26 AM
  6. Count statement wtih multiple criteria only showing results for one criteria
    By uhlabomber in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 07-17-2013, 02:47 PM
  7. Replies: 2
    Last Post: 10-05-2011, 12:43 PM

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