Written by Allen Wyatt (last updated January 18, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365
Eszter has a long list of cells in column A that contain a series of mutation codes, such as "AKT 142" or "BRAF 1975." In column B are values associated with these mutation codes. She needs a formula that will sum the values in column B for which the corresponding mutation code in column A begins with the same sequence, as in all those beginning with AKT or BRAF. Eszter suspects this can be done with the SUMIF function, but she doesn't know how to make it pay attention to only the first part of the mutation code.
There are many ways you could approach this problem, but in this tip, I focus on only three potential solutions.
If your worksheet layout allows, you could add a helper column that contains only the first portion of the mutation codes. Since your mutation codes are in column A, you could insert the following formula in the first cell of your helper column:
=LEFT(A1, SEARCH(" ",A1,1)-1)
Copy it down for as many cells as necessary, and you end up with the helper column containing everything in the mutation codes before the space. You could then use your desired SUMIF formula to sum based on the contents of the helper column.
A rather unique approach to solving the problem is to use the SUMPRODUCT function. Let's say that you put, in cell E1, the preface code you are interested in. (So, for instance, you might put "AKT" into cell E1.) You could then calculate the desired sum by using the following formula:
=SUMPRODUCT(--(LEFT(A:A,LEN($E$1))=$E$1) * B:B)
This works because SUMPRODUCT examines whether the leftmost portion of a cell in column A matches whatever you put in cell E1. If it does, then the comparison returns 1; if it doesn't, it returns 0. This is then multiplied by the corresponding cell in column B and summed.
Perhaps the cleanest approach is to simply use SUMIF directly. You know, from using the helper-column approach, that you can use SUMIF to look at the contents of a cell and then selectively sum another column. You do it in this general manner:
=SUMIF(Check_Range, Criterion, Sum_Range)
Thus, if you wanted to sum values in column B based on what is in column A, you could do the following:
=SUMIF(A:A, "AKT", B:B)
This would, of course, only match those cells in column A that contain just AKT. This is not Eszter's situation, though—the mutation codes in column A contain more than just AKT. This is where the use of wildcards in the criterion specification comes into play. All Eszter needs to do is to add an asterisk, in this manner:
=SUMIF(A:A, "AKT*", B:B)
Now SUMIF returns the proper sum based only on those cells in column A that begin with the letters AKT. It doesn't matter what follows the AKT characters in each cell because the asterisk says to Excel that it should "accept anything that follows those three characters."
You could even make this approach more general in nature. Let's assume that you put the desired preface code (the one on which you want to sum) into cell E1. You could then put the following into cell E2:
=SUMIF(A:A, E1 & "*", B:B)
Now, if E1 contains "AKT" you end up with a sum of values for that preface code. If you change E1 to "BRAF" then you get a sum for that preface code, without a need to change the formula in E2.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13614) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
If you have a mixture of numbers and letters in a cell, you may be looking for a way to access and use the numeric ...
Discover MoreIf you have a series of values in a range of cells, you may wonder how many of those values are even and how many are ...
Discover MoreWhen you are getting the hang of how to put together formulas in Excel, you might run into a situation where you open a ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2025-01-21 15:13:21
J. Woolley
The Tip assumes the mutation codes in column A do not begin with a space and each preface code (like AKT or BRAF) ends with a space. It says, "There are many ways you could approach this problem...."
Re. Using a Helper Column:
If column C is the helper column and the sum is desired for a preface code in cell $E$1 (which must not include a space), then use this formula:
=SUMIF(C:C, $E$1, B:B)
Re. Using SUMPRODUCT:
This formula works just as well as the SUMPRODUCT formula:
=SUM(--(LEFT(A:A, LEN($E$1)) = $E$1) * B:B)
Again, $E$1 must not include a space.
Re. Using SUMIF Directly:
Since the preface code ends with a space, the Tip's formulas containing an asterisk should take this into account. Therefore, they should have a space before the asterisk like this:
=SUMIF(A:A, "AKT *", B:B)
=SUMIF(A:A, $E$1 & " *", B:B)
Otherwise, there would be no difference between preface codes AKT and AKTX, for example, or between BRAF and BRAFX. As before, $E$1 must not include a space.
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments