Summing Based on Part of a Control Cell

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


3

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.

Using a Helper Column

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.

Using SUMPRODUCT

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.

Using SUMIF Directly

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.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Repeating the First Column of a Table

Need the first column of a table to be repeated on multiple pages? You can't do it automatically in Word, but you can use ...

Discover More

Negatives in Pie Charts

Pie charts are a great way to graphically display some types of data. Displaying negative values is not so great in pie ...

Discover More

Referencing Fields in Another Document

Sometimes you may have two documents that are so integrally related to each other that the one document may require the ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2019 For Dummies today!

More ExcelTips (ribbon)

Functions that Can Access Closed Workbooks

When creating a workbook, you can include formulas that reference data stored in other workbooks. Some functions will ...

Discover More

Averaging Based on Multiple Criteria

When you need to determine an average based on a very small selection of cells from a large dataset, based on multiple ...

Discover More

Splitting Cells by Case

Excel provides several different ways that you can split apart the contents of a cell. One way it doesn't provide is to ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is seven less than 7?

2025-01-25 01:33:26

Peter

I assume that Eszter would like a list of totals for all the mutation codes, rather than recording them one at a time. That is, to use an array of unique codes as the second argument in Sumif.
For reasons of simplicity, format the data as a table. Change Column1 heading to "Codes" and Column2 heading to "Number". Insert one table column to the right, change its heading to "Prefix"
In the first row under "Prefix" enter =TEXTBEFORE([@Code]]," "). You don't have to type [@Code], just click on the first value.

In a nearby cell enter =UNIQUE(Table1[Prefix]). In my test it was at E2.
In a cell in an adjacent column enter =SUMIF(Table1[Prefix],E2#,Table1[Number]), Where E2 is the address of the first unique prefix in my test.

Job done.
(see Figure 1 below)

Figure 1. Formula view


2025-01-23 15:17:40

J. Woolley

Here's an interesting problem. What if the mutation codes did not have a space to separate each preface code from the remaining digits? Suppose the mutation codes were like AKT142 or BRAF1975. How would you determine the preface codes?
The following function in My Excel Toolbox returns an array of numeric values beginning with Start incrementing by Step until Finish (not beyond):
    =ForNext(Start, Finish, [Step], [AsColumn])
Start, Finish, and Step can be any numeric value. Default Step is 1.
If AsColumn is FALSE (default), the result is a 1D row array; TRUE returns a 2D column array. Expect N elements: N = 1 + INT((Finish - Start) / Step)
Using ForNext, this formula returns the preface code for cell A1:
    =LEFT(A1, SUM(--ISERROR(VALUE(MID(A1, ForNext(1, LEN(A1)), 1)))))
MID(...) returns an array containing each character. VALUE(...) returns an error if the character is not a digit (0,1,2...). Double unary (--) converts TRUE/FALSE into 1/0. So the formula returns AKT if cell A1 is AKT142 or BRAF if it is BRAF1975.
This formula uses the SEQUENCE function in Excel 2021 to return the same result:
    =LEFT(A1, SUM(--ISERROR(VALUE(MID(A1, SEQUENCE(LEN(A1)), 1)))))
For older versions of Excel,
    SEQUENCE(LEN(A1))
can be replaced by
    ROW(INDIRECT("1:" & LEN(A1)))
My Excel Toolbox also includes the following regular expression function:
    =RegExMatch(Text, Pattern, [Mode], [IgnoreCase], [Multiline])
This is similar to Excel's new REGEXEXTRACT function described here: https://support.microsoft.com/Search/results?query=REGEXEXTRACT
Therefore, these formulas also return the preface code for cell A1 (which is assumed to be upper case):
    =RegExMatch(A1, "[A-Z]+")
    =REGEXEXTRACT(A1, "[A-Z]+")
These functions use the VBScript 5.5 regular expression syntax described here:
https://learn.microsoft.com/en-us/previous-versions/1400241x(v=vs.85)
Or here: https://drive.google.com/file/d/1qWS2qLib0sL_u6Sh95FuEeZxRzzr4SUE/view
See https://sites.google.com/view/MyExcelToolbox/


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.


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.