+ Reply to Thread
Results 1 to 7 of 7

Sum Sumifs on multiple range with multiple criteria in each range

  1. #1
    Registered User
    Join Date
    01-24-2023
    Location
    France
    MS-Off Ver
    365
    Posts
    3

    Sum Sumifs on multiple range with multiple criteria in each range

    Hello,

    i've been working on a "to-be" dashboard for a long time, and i'm now stuck on a sum i need to do based on the selection of four segment
    the criteria are generated in 4 differente tables from a UNIQUE(Filter formula

    i need a first sum based on the criteria affecting the column " Client ", " Carrier " and " Temperature " regardless of the range" imputation "
    and another one based on the same thing, but with the column " imputation " added

    i've tried with Sum(SumIFS , but it seem sumifs can't work with this many criteria

    i've tried to look at sumproduct but i don't really understand how it work

    could you please look at my file and tell me where i'm going wrong ?

    thanks in advance,

  2. #2
    Forum Expert
    Join Date
    02-11-2014
    Location
    New York
    MS-Off Ver
    Excel 365 (Windows)
    Posts
    5,942

    Re: Sum Sumifs on multiple range with multiple criteria in each range

    You're overthinking it: anything that is all or any can just be ignored in the formula.

    Sum everything:

    =SUM(K:K)

    Sum only the imputation is "Carrier" or "Recipient" etc based on the segment:

    =SUMIF(I:I,"Carrier",K:K)
    =SUMIF(I:I,"Recipient",K:K)
    or either:
    =SUM(SUMIF(I:I,{"Carrier","Recipient"},K:K))
    Bernie Deitrick
    Excel MVP 2000-2010

  3. #3
    Registered User
    Join Date
    01-24-2023
    Location
    France
    MS-Off Ver
    365
    Posts
    3

    Re: Sum Sumifs on multiple range with multiple criteria in each range

    Quote Originally Posted by Bernie Deitrick View Post
    You're overthinking it: anything that is all or any can just be ignored in the formula.

    Sum everything:

    =SUM(K:K)

    Sum only the imputation is "Carrier" or "Recipient" etc based on the segment:

    =SUMIF(I:I,"Carrier",K:K)
    =SUMIF(I:I,"Recipient",K:K)
    or either:
    =SUM(SUMIF(I:I,{"Carrier","Recipient"},K:K))
    Hello, I may not have been clear enough,

    The formula need to work with any type of criteria filtered with the segment

    I know I could write the criteria directly in the formula, but each filtering change the criteria needed on each of the four rznge
    So your solution don't fit with what I need

    Or I really don't understand your thinking

  4. #4
    Forum Expert
    Join Date
    02-11-2014
    Location
    New York
    MS-Off Ver
    Excel 365 (Windows)
    Posts
    5,942

    Re: Sum Sumifs on multiple range with multiple criteria in each range

    Sorry - I mis-interpreted what you need.

    If you are filtering your data table, you could use =SUBTOTAL(9,RangeToSum) which will respond to your selection of filters no matter how complex.

    Otherwise, I would use a pivot table, and apply filters to it, with the data area set to SUM.

    Otherwise, I'm not sure what it is that you want to do....

  5. #5
    Forum Guru
    Join Date
    05-24-2011
    Location
    India
    MS-Off Ver
    Office 2021
    Posts
    2,237

    Re: Sum Sumifs on multiple range with multiple criteria in each range

    Hello,

    Try these formulas.

    Please Login or Register  to view this content.
    Please Login or Register  to view this content.
    Regards,
    Haseeb Avarakkan

    __________________________________
    "Feedback is the breakfast of champions"

  6. #6
    Registered User
    Join Date
    01-24-2023
    Location
    France
    MS-Off Ver
    365
    Posts
    3

    Re: Sum Sumifs on multiple range with multiple criteria in each range

    Quote Originally Posted by Haseeb A View Post
    Hello,

    Try these formulas.

    Please Login or Register  to view this content.
    Please Login or Register  to view this content.
    Hello

    Thank you , it was the solution i was looking for, i really have to find some time to learn the know-how about SUMPROD.
    if i may ask, you wouldn't happen to know of a good guide to this Formula ? ^^

    To Bernie Deitrick, i also thank you for your help, i have yet to try the subtotal function, but i will try to play around with it.

  7. #7
    Forum Guru
    Join Date
    05-24-2011
    Location
    India
    MS-Off Ver
    Office 2021
    Posts
    2,237

    Re: Sum Sumifs on multiple range with multiple criteria in each range

    Glad the formula works.

    ISNUMBER(MATCH(RemiseSAPTM_avec_imputation[Client],Tableau11[Client],0))

    MATCH formula compare two ranges. Gives its position number where that stand in Client table. If NO match found gives error. So it will be like an array of {1;#N/A;#N/A;6;1;4;#N/A....}

    ISNUMBER will convert TRUE if match found, otherwise FALSE. So basically this will create an array of TRUE/FALSE values (ie, {TRUE;FALSE;FALSE;TRUE;TRUE;TRUE;FALSE;.........}

    Repeat the same formula for other conditions. just update the range & table names.

    ISNUMBER(MATCH(RemiseSAPTM_avec_imputation[Client],Tableau11[Client],0))*ISNUMBER(MATCH(RemiseSAPTM_avec_imputation[Carrier],Tableau10[Carrier],0))*ISNUMBER(MATCH(RemiseSAPTM_avec_imputation[Temperature],Tableau14[Temperature],0))

    These formulas, we get an array of TRUE/FALSE values and multiply them each other will get 1 or 0,

    Lets say if the output produced by ISNUMBER(MATCH... is {TRUE;FALSE;TRUE}*{TRUE;FALSE;FALSE}*{TRUE;TRUE;TRUE}

    TRUE*TRUE = 1 (All should be TRUE. If any of the result is FALSE, will give 0)
    TRUE*FALSE = 0
    FALSE*FALSE = 0

    So, the array will give values of 0 and 1.

    The sum range in the SUMPRODUCT is RemiseSAPTM_avec_imputation[Total UM], so SUMPRODUCT will take value from only where the array result is 1.

    In text, If all the conditions mentioned are TRUE, then take appropriate number from the sum range and sum it.

    I hope the explanation is helpful. I am not good at explaining something

+ 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. Sumifs multiple criteria same range
    By macok in forum Office 365
    Replies: 1
    Last Post: 09-30-2021, 06:58 PM
  2. SUMIFs with multiple criteria in one column range
    By zainmerchant in forum Excel Formulas & Functions
    Replies: 19
    Last Post: 03-04-2020, 11:06 AM
  3. [SOLVED] Sumifs with multiple criteria (where one is a range) ?
    By Jeferson11 in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 01-23-2019, 12:10 PM
  4. Sumifs criteria between multiple range in single cells
    By silambarasan.J in forum Excel General
    Replies: 3
    Last Post: 08-18-2015, 05:57 AM
  5. Replies: 3
    Last Post: 11-21-2012, 04:57 PM
  6. SUMIFS with multiple values for one criteria range
    By Harsha Haridas in forum Excel General
    Replies: 9
    Last Post: 01-27-2012, 06:08 AM
  7. Replies: 1
    Last Post: 05-16-2011, 05:00 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