+ Reply to Thread
Results 1 to 10 of 10

SUMIFS with multiple values for one criteria range

  1. #1
    Registered User
    Join Date
    05-06-2009
    Location
    India
    MS-Off Ver
    Excel 2007
    Posts
    3

    SUMIFS with multiple values for one criteria range

    I am using Excel 2007 to analyse soem data. I need to get the total amount based on some criteria. I know SUMIFS can be used for this. Please see the attached excel sheet. I am using the below formula to calculate the total amount.
    =SUMIFS(C2:C16,A2:A16,"Jan",B2:B16,"Fri")+SUMIFS(C2:C16,A2:A16,"Jan",B2:B16,"Mon")+SUMIFS(C2:C16,A2:A16,"Feb",B2:B16,"Fri")+SUMIFS(C2:C16,A2:A16,"Feb",B2:B16,"Mon")

    This is only an example. The actual calculation I am trying to do involve more than 500 rows. So I need a better solution.

    This is what i am looking for:
    SUM Amount if ( (Month is equal to 'Jan' or 'Feb') AND (Day is equal to 'Mon' or 'Fri')

    That is, a formula in which i can give multiple values for one range. Can some one help me with an Excel 2007 formula for this?
    Attached Files Attached Files

  2. #2
    Forum Moderator zbor's Avatar
    Join Date
    02-10-2009
    Location
    Croatia
    MS-Off Ver
    365 ProPlus
    Posts
    15,596

    Re: SUMIFS with multiple values for one criteria range

    hOW ABOUT SOMETHING LIKE THIS?

    SUMIFS(1).xlsx

    Ups.. caps lock

  3. #3
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: SUMIFS with multiple values for one criteria range

    i believe you can do up to 27 criteria
    so perhaps
    sumifs(C2:C16,A2:A16,"Jan",B2:B16,"Fri",A2:A16,"feb",B2:B16,"Fri",A2:A16,"Jan",B2:B16,"mon",A2:A16,"feb",B2:B16,"mon")
    "Unless otherwise stated all my comments are directed at OP"

    Mojito connoisseur and now happily retired
    where does code go ?
    look here
    how to insert code

    how to enter array formula

    why use -- in sumproduct
    recommended reading
    wiki Mojito

    how to say no convincingly

    most important thing you need
    Martin Wilson: SPV
    and RSMBC

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

    Re: SUMIFS with multiple values for one criteria range

    That will give you a sum of zero Martin, because all criteria need to be satisfied. Using SUMPRODUCT

    =SUMPRODUCT(C2:C16,--ISNUMBER(MATCH(A2:A16,{"Jan","Feb"},0)),--ISNUMBER(MATCH,B2:B16,{"Fri","Mon"},0)))

  5. #5
    Registered User
    Join Date
    05-06-2009
    Location
    India
    MS-Off Ver
    Excel 2007
    Posts
    3

    Unhappy Re: SUMIFS with multiple values for one criteria range

    Tried the below formula suggested.
    =SUMPRODUCT(C2:C16,--ISNUMBER(MATCH(A2:A16,{"Jan","Feb"},0)),--ISNUMBER(MATCH,B2:B16,{"Fri","Mon"},0)))

    But I am getting an error "You have entered too many arguments for this function".

  6. #6
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: SUMIFS with multiple values for one criteria range

    missing a "("

    =SUMPRODUCT(C2:C16,--ISNUMBER(MATCH(A2:A16,{"Jan","Feb"},0)),--ISNUMBER(MATCH(B2:B16,{"Fri","Mon"},0)))

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

    Re: SUMIFS with multiple values for one criteria range

    Apologies,

    as Martin says, missing parenthesis, thanks Martin

    I ignored the golden rule....."Always test your formulas"

  8. #8
    Registered User
    Join Date
    05-06-2009
    Location
    India
    MS-Off Ver
    Excel 2007
    Posts
    3

    Smile Re: SUMIFS with multiple values for one criteria range

    Thanks a lot. This worked.

    One more query: Can I use wild card serch (instead of "Jan", can I use "J*" so that I get values corresponding to Jan, June and July) in SUMPRODUCT?

  9. #9
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: SUMIFS with multiple values for one criteria range

    TRY
    =SUMPRODUCT(C2:C16,--ISNUMBER(SEARCH("J*",A2:A16)),--ISNUMBER(MATCH(B2:B16,{"Fri","Mon"},0)))

  10. #10
    Registered User
    Join Date
    01-27-2012
    Location
    NL
    MS-Off Ver
    Excel 2007
    Posts
    1

    Re: SUMIFS with multiple values for one criteria range

    Although this thread is already quite for some time, I try to get a solution for the following challenge. I try to sum the values based on multiple criteria and criteria ranges using the following formula:

    =IF(F$3="Yes", SUMIFS(Backlog!$F:$F, Backlog!$C:$C, "Task", Backlog!$E:$E, "Unplanned", Backlog!$H:$H, Sprint_ID, Backlog!$J:$J, 'Burn down'!F$2), NA())

    Now what I would like to add is a check for the range Backlog!$I:$I being equal to either "Added"or "Done". Using the example above results in creating the following formula:
    =SUMPRODUCT(Backlog!$F:$F, --(Backlog!$C:$C = "Task"), --(Backlog!$E:$E="Unplanned"), --(Backlog!$H:$H=Sprint_ID), --(Backlog!$I:$I={"Done","Added"}), --(Backlog!$J:$J= 'Burn down'!F$2))

    Although is not yet equal to the SUMIFS as shown earlier (still need to add the precondition), the formula returns me a #value

    When I change the condition --(Backlog!$I:$I={"Done","Added"}) to --(Backlog!$I:$I={"Done",}) the formula returns me a number (which is expected) but now is doing basically the same as the SUMIFS shown earlier.

    How can I make this formula to work with both conditions?

    Thank you!

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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