Conditional SUMIF using two criteria

DCPAus

Board Regular
Joined
Nov 7, 2002
Messages
90
I would like to do a conditional sumif using two criteria. I am able to do this using CSE's or using the Conditional Sum Wizard, the problem I encounter though is that I need to use a wildcard.

Example
This is using the Condtional Sum Wizard
=SUM(IF($A$20:$A$50=E56,IF($C$20:$C$50=F56,$G$20:$G$50,0),0))

but what I would like is something like this
=SUM(IF($A$20:$A$50="Test",IF($C$20:$C$50="Car*",$G$20:$G$50,0),0))

The wildcard is so that all variations are acounted for.

Does anyone know how to do this
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
There may be a better way, but I had a thought that may work as well.

You could use the LEFT function for the second if range (C20:C50) e.g. LEFT(c20:c50,3)="Car"

i know you can use Wildcard charcaters for VLOOKUPS and such, I'm sure some of the great minds here will be able to state whether you can use them in SUMs

Good luck
 
Upvote 0
I would like to do a conditional sumif using two criteria. I am able to do this using CSE's or using the Conditional Sum Wizard, the problem I encounter though is that I need to use a wildcard.

Example
This is using the Condtional Sum Wizard
=SUM(IF($A$20:$A$50=E56,IF($C$20:$C$50=F56,$G$20:$G$50,0),0))

but what I would like is something like this
=SUM(IF($A$20:$A$50="Test",IF($C$20:$C$50="Car*",$G$20:$G$50,0),0))

The wildcard is so that all variations are acounted for.

Does anyone know how to do this

You can use Sumproduct as in

=SUMPRODUCT(--(ISNUMBER(SEARCH("Car",C2:C50))),--(A2:A50="Test"),G2:G50)
 
Upvote 0
You can use Sumproduct as in

=SUMPRODUCT(--(ISNUMBER(SEARCH("Car",C2:C50))),--(A2:A50="Test"),G2:G50)

Hi Brian

Above worked incredibly well. Thanks very much.
 
Upvote 0

Forum statistics

Threads
1,213,543
Messages
6,114,243
Members
448,555
Latest member
RobertJones1986

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