Summing When the First Character Matches a Value

Written by Allen Wyatt (last updated October 22, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365


George has a worksheet where the first row, in the range B1:AK1, contains part numbers. Some part numbers begin with X and others begin with Y. He wonders if there is a way to use SUMIF (or some other function) to sum the range B2:AK212 only for those columns in which the first cell in the column (B1:AK1) contains an "X" as the first character in the part number.

One way to accomplish this task is to use the SUMPRODUCT function along with the LEFT function to determine if the part number in the first row starts with an X or not:

=SUMPRODUCT((LEFT(B$1:AK$1,1)="X")*B2:AK212)

The LEFT function returns the leftmost character of the part number and compares it to X. If it is equal, then the result is 1; if not equal then it is 0. This resulting value (1 or 0) is then multiplied by the individual cells in the data range. The result is your desired sum.

If you must use the SUMIF function for some reason, there are two ways you could approach the problem. First, you could add the following into cell AL2:

=SUMIF(B$1:AK$1,"X*",B2:AK2)

This results in a sum of just the cells in row 2 that have a part number beginning with X. Copy the cell downward to cells AL3:AL212, and then sum the column.

The other approach is to add a totals row at the bottom of your data. Thus, you could use the following in cell B213:

=SUM(B2:B212)

Copy this formula to the other cells on the row (C213 through AK213) and then you can use this formula to get your desired sum:

=SUMIF(B1:AK1,"X*",B213:AK213)

In this case, SUMIF is checking the first row (where the part numbers are) and summing the appropriate cells from the totals you just added in row 213.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13471) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, 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

Macro Runs Slowly, but Steps Quickly

When you have a macro that processes a huge amount of data, it can seem like it takes forever to finish up. These ...

Discover More

Leaving a Cell Value Unchanged If a Condition Is False

Ever want the IF function to only return a value if the condition it is testing is true, and not if the condition is ...

Discover More

Hiding Grammar Errors

Are you bothered by the green underlines that Word uses to mark potential grammar errors in your document? You can hide ...

Discover More

Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!

More ExcelTips (ribbon)

Strange Formula Conversions

When you are getting the hang of how to put together formulas in Excel, you might run into a situation where you open a ...

Discover More

Searching for a Value Using a Function

Searching for a value using Excel's Find tool is easy; searching for that same value using a formula or a macro is more ...

Discover More

Generating Random Strings

Do you need to generate strings of random characters? The ideas presented in this tip will help you do it in a hurry.

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 5 - 2?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.