SUMIFS Using Dropdown Lists

Detectiveclem

Active Member
Joined
May 31, 2014
Messages
320
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
  2. MacOS
Hello,<o:p></o:p>
I have set up a successful SUMIFS using two criteria toprovide a total figure depending on the criteria selected from the drop-downlist for both criteria (=SUMIFS(B2:B40,A2:A40,F40,C2:C40,G40). <o:p></o:p>
Range B2:B40 contains number values<o:p></o:p>
Range A2:A40 contains any of the following; Complete,Awaits, On Going, Issue.<o:p></o:p>

Range C2:C40 contains any of the following; Team A, Team B,Team C, Team D<o:p></o:p>
Cell F40 (Contains the following drop down text: - Complete,Awaits, On Going, Issue). <o:p></o:p>
Cell G40 (Contains the following drop down text: - Team A,Team B, Team C, Team D)<o:p></o:p>
All relatively straight forward so far, however I want tohave the ability of including the word ALL in both drop-down lists, which wouldthen include all the criteria field data. <o:p></o:p>
I.E. If Criteria 1 is selected to ALL and Criteria 2 is TeamC then the result will show the total of all fields for Team C only. And soforth.<o:p></o:p>
However as none on the data range includes the text ‘ALL’ I obviouslyget a zero result. Is there any way I can achieve this by changing the formulaor by using wildcards, or by some other means?<o:p></o:p>
Grateful for any assistance in this matter. <o:p></o:p>
 

Excel Facts

What is =ROMAN(40) in Excel?
The Roman numeral for 40 is XL. Bill "MrExcel" Jelen's 40th book was called MrExcel XL.
Hi,

Add all to your drop down list and use the below formula for your results cell,
Should do the trick

=IF(F40="All",SUMIF($C$2:$C$40,$G$40,B2:B40),SUMIFS(B2:B40,A2:A40,F40,C2:C40,G40))
 
Upvote 0
Just realised you want to be able to select 'All' for both criteria,
In this case, Add an 'All' selection to both drop down lists and use the following formula in your results cell.

=IF(AND($F$40="All",$G$40="All"),SUM($B$2:$B$40),IF($F$40="All",SUMIF($C$2:$C$40,$G$40,$B$2:$B$40),IF($G$40="All",SUMIF($A$2:$A$40,$F$40,$B$2:$B$40),SUMIFS($B$2:$B$40,$A$2:$A$40,$F$40,$C$2:$C$40,$G$40))))
 
Upvote 0
Thank you Cunnyace, I will try it later, but really appreciate your help.
 
Upvote 0
Hello again cunningAce,

Just tried your formula and it works brilliantly. Thank you for taking the time to resolve my issue.

Very much appreciated.
 
Upvote 0
Hi Aladin, sorry for the delay in replying. Your formula works perfectly. Thank you
 
Upvote 0

Forum statistics

Threads
1,213,494
Messages
6,113,972
Members
448,537
Latest member
Et_Cetera

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top