Exceljet

Quick, clean, and to the point

Sum 2d range with multiple criteria

Excel formula: Sum 2d range with multiple criteria
Generic formula 
=SUMPRODUCT(data*(range1=criteria1)*(range2=criteria2))
Explanation 

To lookup and sum values in a 2D range with multiple criteria, you can use the SUMPRODUCT function. In the example shown, the formula in J6 is:

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

using named ranges as shown in the image.

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.

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.

Excel foundational video course
Excel Pivot Table video training course
Excel formulas and functions video training course
Excel Shortcuts Video Course
Excel Charts video training course
Video training for Excel Tables