SUMIF, looking for string values within an array

TomH01

New Member
Joined
Feb 5, 2014
Messages
10
I need to sum a range if a string is contained within an array of values.

A
B
C
1
Critieria
Range
Sum Range
2
Product1Half Product140
3
Product2Product1250
4
Product3Some Product234
5
Product342
6
All Product350

<tbody>
</tbody>

In this instance I'd want to sum the whole range, as the critiera is contained within each of the cells. I've tried using SUMIFS but that only works on exact matching the criteria to the range.

Any help would be much appreciated.
 

Some videos you may like

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092
You can use wildcards (* and ?) in SUMIF(S):

<b>Excel 2010</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #BBB"><colgroup><col width="25px" style="background-color: #DAE7F5" /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #DAE7F5;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style=";">Criteria</td><td style=";">Range</td><td style=";">Sum Range</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">Product1</td><td style=";">Half Product1</td><td style="text-align: right;;">40</td><td style="text-align: right;;">416</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">Product2</td><td style=";">Product1</td><td style="text-align: right;;">250</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">Product3</td><td style=";">Some Product2</td><td style="text-align: right;;">34</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;"></td><td style=";">Product3</td><td style="text-align: right;;">42</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;"></td><td style=";">All Product3</td><td style="text-align: right;;">50</td><td style="text-align: right;;"></td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #BBB;border-top:none;text-align: center;background-color: #DAE7F5;color: #161120">Sheet1</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #BBB"><thead><tr style=" background-color: #DAE7F5;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">D2</th><td style="text-align:left">=SUMPRODUCT(<font color="Blue">SUMIF(<font color="Red">B2:B6,"*"&A2:A4&"*",C2:C6</font>)</font>)</td></tr></tbody></table></td></tr></table><br />
 

TomH01

New Member
Joined
Feb 5, 2014
Messages
10
You can use wildcards (* and ?) in SUMIF(S):

Excel 2010
ABCD
1CriteriaRangeSum Range
2Product1Half Product140416
3Product2Product1250
4Product3Some Product234
5Product342
6All Product350

<colgroup><col style="width: 25pxpx"><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
D2=SUMPRODUCT(SUMIF(B2:B6,"*"&A2:A4&"*",C2:C6))

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>

That's great, thanks for that. I'd been trying the wild cards but wasn't getting the syntax quite right.
 

Watch MrExcel Video

Forum statistics

Threads
1,122,719
Messages
5,597,736
Members
414,170
Latest member
Mdm

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
Top