Exceljet

Quick, clean, and to the point

Average pay per week

Excel formula: Average pay per week
Generic formula 
=SUMPRODUCT(hours*rate)/COUNTIF(hours,">0")
Explanation 

To calculate average pay per week, excluding weeks where no hours were logged, and without total pay per week already calculated, you can use a formula based on the SUMPRODUCT and COUNTIF functions. In the example shown, the formula in J5 is:

=SUMPRODUCT(D5:I5*D6:I6)/COUNTIF(D5:I5,">0")

which returns the average pay per week, excluding weeks where no hours were logged. This is an array formula, but it is not necessary to enter with control + shift + enter because the SUMPRODUCT function can natively handle most array operations.

How this formula works

You might first think this problem can be solved with the AVERAGEIF or AVERAGEIFS function. However, because total pay per week is not part of the worksheet, we can't use these functions because they require a range. 

Working from the inside out, we first calculate total pay for all weeks:

D5:I5*D6:I6 // total pay for all weeks

This is array operation that multiplies hours by rates to calculate weekly pay amounts. The result is an array like this:

{87,63,48,0,12,0} // weekly pay amounts

Since there are 6 weeks in the worksheet, the array contains 6 values. This array is returned directly to SUMPRODUCT function:

SUMPRODUCT({348,252,192,0,48,0})

The SUMPRODUCT function then returns the sum of items in the array, 840. At this point, we have:

=840/COUNTIF(D5:I5,">0")

Next, the COUNTIF function returns a count of values greater than zero in the range D5:I5. Since 2 of the 6 values are blank, and Excel evaluates blank cells as zero, COUNTIF returns 4.

=840/4
=210

The final result is 840 divided by 4, which equals 210

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