Summary

To sum values in columns by matching column headers, you can use a formula based on the SUMPRODUCT function. In the example shown, the formula in J5 is:

=SUMPRODUCT(data*(LEFT(headers)=J4))

where data is the named range B5:G14, and headers is the named range B4:G4. The formula sums columns where headers begin with "A" and returns 201.

Note: In the current version of Excel you can also use the FILTER function, as explained below.

Generic formula

=SUMPRODUCT(data*(headers=A1))

Explanation 

At the core, this formula relies on the SUMPRODUCT function to sum values in matching columns in the named range data C5:G14. If all data were provided to SUMPRODUCT in a single range, the result would be the sum of all values in the range:

=SUMPRODUCT(data) // all data, returns 387

To apply a filter by matching column headers – columns with headers that begin with "A" – we use the LEFT function like this:

LEFT(headers)=J4) // must begin with "a"

This expression returns TRUE if a column header begins with "a", and FALSE if not. The result is an array:

{TRUE,TRUE,FALSE,FALSE,TRUE,FALSE}

You can see that values 1,2, and 5 correspond to columns that begin with "a".

Inside SUMPRODUCT, this array is multiplied by "data". Due to broadcasting, the result is a two-dimensional array like this:

{8,10,0,0,7,0;9,10,0,0,10,0;8,6,0,0,6,0;7,6,0,0,6,0;8,6,0,0,6,0;10,11,0,0,7,0;7,8,0,0,8,0;2,3,0,0,3,0;3,4,0,0,4,0;7,7,0,0,4,0}

If we visualize this array in a table, it's easy to see that only values in columns that begin with "a" have survived the operation, all other columns are zero. In other words, the filter keeps values of interest and "cancels out" the rest:

A001 A002 B001 B002 A003 B003
8 10 0 0 7 0
9 10 0 0 10 0
8 6 0 0 6 0
7 6 0 0 6 0
8 6 0 0 6 0
10 11 0 0 7 0
7 8 0 0 8 0
2 3 0 0 3 0
3 4 0 0 4 0
7 7 0 0 4 0

With only a single array to process, SUMPRODUCT returns the sum of all values, 201.

Sum by exact match

The example above shows how to sum columns that begin with one or more specific characters. To sum column based on an exact match, you can use a simpler formula like this:

=SUMPRODUCT(data*(headers=J4))

FILTER function

In the latest version of Excel, you can solve this problem more directly with the FILTER function like this:

=SUM(FILTER(data,LEFT(headers)=J4,0))

In this formula, we use the same logic we used in the SUMPRODUCT function to select only data in columns that begin with the letter "A":

LEFT(headers)=J4 // columns that begin with "A"

The expression above returns an array of TRUE and FALSE values like this:

{TRUE,TRUE,FALSE,FALSE,TRUE,FALSE}

Notice that the TRUE values correspond to column headers that begin with "A". The FILTER function uses this array to select columns in the named range data. Because this array is horizontal, FILTER automatically filters on columns. The FILTER function returns the 3 columns in data with headers that begin with "A" to the SUM function, which returns a final result of 201.

Dave Bruns Profile Picture

AuthorMicrosoft Most Valuable Professional Award

Dave Bruns

Hi - I'm Dave Bruns, and I run Exceljet with my wife, Lisa. Our goal is to help you work faster in Excel. We create short videos, and clear examples of formulas, functions, pivot tables, conditional formatting, and charts.