Exceljet

Quick, clean, and to the point

Sum matching columns and rows

Excel formula: Sum matching columns and rows
Generic formula 
=SUMPRODUCT(data*(range1=criteria1)*(range2=criteria2))
Explanation 

To sum values in matching columns and rows, you can use the SUMPRODUCT function. In the example shown, the formula in J6 is:

=SUMPRODUCT(data*(codes=J4)*(days=J5))

where data (C5:C14), days (B5:B14), and codes (C4:G4) are named ranges.

How this formula works

The SUMPRODUCT function can handle arrays natively, without requiring control shift enter.

In this case, we are multiplying all values in the named range data by two expressions that filter out values not of interest. The first expression applies a filter based on codes:

(codes=J4)

Since J4 contains "A002", the expression creates an array of TRUE FALSE values like this:

{FALSE,TRUE,FALSE,FALSE,FALSE}

The second expression filters on day:

(days=J5)

Since J4 contains "Wed", the expression creates an array of TRUE FALSE values like this:

{FALSE;FALSE;TRUE;FALSE;FALSE;FALSE;FALSE;TRUE;FALSE;FALSE}

In Excel, TRUE FALSE values are automatically coerced to 1 and 0 values by any math operation, so the multiplication operation coerces the arrays above to ones and zeros, and creates a 2D array with the same dimensions as the original data. The process can be visualized as shown below:

Array multiplication inside SUMPRODUCT

Finally, SUMPRODUCT returns the sum of all elements in the final array, 9.

Notes:

  1. Although the example shows only one matched column, this formula will correctly sum multiple matched columns.
  2. If you only need to match columns (not rows) you can use a formula like this.
  3. To only match rows, you can use the COUNTIFS function.
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.