Exceljet

Quick, clean, and to the point

Sum matching columns

Excel formula: Sum matching columns
Generic formula 
=SUMPRODUCT(data*(headers=A1))
Explanation 

To sum values in columns by matching 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 C5:G14, and "headers" is the named range C4:G4.

The formula sums columns where headers begin with "a" and returns 201.

How this formula works

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.

Author 
Dave Bruns

Excel Formula Training

Formulas are the key to getting things done in Excel. In this accelerated training, you'll learn how to use formulas to manipulate text, work with dates and times, lookup values with VLOOKUP and INDEX & MATCH, count and sum with criteria, dynamically rank values, and create dynamic ranges. You'll also learn how to troubleshoot, trace errors, and fix problems. Instant access. See details here.