Summary

To calculate an average by group with a formula, you can use an Excel Table, the UNIQUE function, and the AVERAGEIFS function connected to the spill range returned by UNIQUE. In the example shown, the formula in cell G5 is:

=AVERAGEIFS(data[Score],data[Group],F5#)

Where data is an Excel Table in the range B5:D16. The result from AVERAGEIFS spills into the range G5:G7. 

Note: Dynamic Array Formulas are available in Excel 365 and Excel 2021. In older versions you can manually enter the group values in F5:F7 and use the standard AVERAGEIFS formula explained below.

Generic formula

=AVERAGEIFS(avg_range,criteria_range,criteria)

Explanation 

In this example, the goal is to create a formula that calculates an average by group, using the group names in column C. The solution shown requires three general steps:

  1. Create an Excel Table called data
  2. List unique groups with the UNIQUE function
  3. Calculate averages with the AVERAGEIFS function

Create the Excel Table

One of the key features of an Excel Table is its ability to dynamically resize when rows are added or removed. In this case, all we need to do is create a new table named data with the data shown in B5:D16.  You can use the keyboard shortcut Control + T.

Video: How to create an Excel table

The table will now automatically expand or contract as needed when new data is added or removed.

List unique groups

The next step is to list the unique group values in column C starting in cell F5. For this we use the UNIQUE function. The formula in F5 is:

=UNIQUE(data[Group]) // unique groups

The result from UNIQUE is an array with 3 values like this:

{"A";"B";"C"}

This array lands as a spill range in cell F5 and lists all of the unique groups in the Group column of the table. The UNIQUE function will continue to output a list of unique groups, even if new groups are added to the data.

Video: Intro to the UNIQUE function

Video: What is an array?

Calculate average

We now have what we need to calculate the average for each group. Our task is to calculate an average based on one criteria: the group name. A good way to do this is to use the AVERAGEIFS function, which is designed to calculate averages based on one or more criteria. Because we have unique groups in a spill range, we can point to this list directly. The formula in G5 is:

=AVERAGEIFS(data[Score],data[Group],F5#)

The first argument in AVERAGEIFS is average_range. This is the range that contains numbers to average. In this example, this is the Score column in the table:

=AVERAGEIFS(data[Score],

The next two arguments specify the criteria. The criteria range is data[Group], and the criteria is the spill range:

=AVERAGEIFS(data[Score],data[Group],F5#)

Because the spill range F5# contains 3 values, the AVERAGEIFS function returns 3 averages in an array like this:

{77.75;73.25;87.25}

Each number in the array is the average calculated for a group. These values spill into the range G5:G7.

When data changes

The key advantage to this approach is that it responds instantly to changes in the data. If new rows are added that refer to existing groups, the spill range returned by UNIQUE remains unchanged, and AVERAGEIFS calculates an updated set of averages. If new rows are added that include new groups, or if existing group values are changed, these changes are captured by the UNIQUE function, which expands the spill range in F5 if needed. If rows are deleted from the table, the spill range contracts as needed. In all cases, the spill range represents the current list of unique groups, and the AVERAGEIFS function uses this list to calculate averages.

Legacy Excel

In older versions of Excel without the UNIQUE function, the approach needs to be modified slightly. Instead of using the UNIQUE function to automatically extract unique groups, the groups can be entered manually. Then the formula in G5 becomes:

=AVERAGEIFS(data[Score],data[Group],F5)

Note the criteria is no longer a spill range. This formula can then be copied down to return an average for each group.

Note: there are ways to extract unique values in older versions of Excel, but they are more complicated.

Pivot Table option

A pivot table would also be a good way to solve this problem, and would provide additional features. However, one drawback is that pivot tables need to be refreshed to show the latest data. Formulas, on the other hand, update instantly when data changes.

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.