Dynamic two-way count

=COUNTIFS(table[column1],spill1#,table[column2],spill2#)
To perform a dynamic two-way count with a formula, you can use an Excel Table, the UNIQUE function, and the COUNTIFS function connected to the spill ranges returned by UNIQUE. In the example shown, the formula in cell G5 is:
=COUNTIFS(data[Color],F5#,data[Size],G4#)
Where "data" is an Excel Table based on the data in B5:D16. The result from COUNTIFS spills into the range G5:I9. Note the result from COUNTIFS is a count of records that meet criteria. See below for a formula to sum the Qty column using the same criteria.
In this example, the goal is to create a formula that performs a dynamic two-way count of all color and size combinations in the range B5:D16 . The solution shown requires four general steps:
- Create an Excel Table called "data"
- List unique colors with UNIQUE function
- List unique sizes with UNIQUE function
- Generate counts in COUNTIFS function
Create the Excel Table
One of the key benefits of an Excel Table is its ability to 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.
Video: How to create an Excel table
The table will now automatically expand or contract as needed.
List unique colors
The next step is to list the unique colors in the "Color" column starting in cell F5. For this we use the UNIQUE function. The formula in F5 is:
=UNIQUE(data[Color]) // unique colors
This is what makes this solution dynamic. The UNIQUE function will continue to output a list of unique colors, even when data in the table changes.
Video: Intro to the UNIQUE function
List unique sizes
Two perform a two-way count, we also need a list of unique sizes starting in cell G4. We can do this with a formula just like the one we used for colors:
UNIQUE(data[Size]) // unique sizes
However, unlike colors, we need this list to run horizontally. To change the output from vertical to horizontal, we nest the UNIQUE formula in the TRANSPOSE function. The formula in G4 is:
The UNIQUE function returns a vertical array like this:
{"L";"M";"S"}
And the TRANSPOSE function converts this array into a horizontal array like this:
{"L","M","S"}
Note the commas instead of semicolons in the second array.
Video: What is an array?
Calculate unique counts
We now have what we need to calculate the counts. Because we have both unique sizes and unique colors on the worksheet as spill ranges, we can use the COUNTIFS function for this task. The formula in G5 is:
=COUNTIFS(data[Color],F5#,data[Size],G4#)
With COUNTIFS, conditions are entered in range/criteria pairs. The first pair targets colors:
data[Color],F5# // all colors, unique colors
The second range/criteria pair targets sizes:
data[Size],G4# // all sizes, unique sizes
When data changes
The key advantage to this formula approach is that it instantly responds to changes in the data. If new rows are added that refer to existing colors and sizes, the spill ranges returned by COUNTIFS are unchanged, and COUNTIFS simply returns an updated set of counts. If new rows are added that include new colors and/or new sizes, these are captured by the UNIQUE function, which expands the spill ranges as needed. If rows are deleted from the table, spill ranges contract if needed. In all cases, the spill ranges represent the current list of unique colors and sizes, and the COUNTIFS function uses these values to return a current set of counts.
Pivot Table option
A pivot table would also be an excellent way to solve this problem, and would provide additional capabilities. 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.
Dynamic two-way sum
The example above performs a dynamic two-way count. However, you can easily create a dynamic two-way sum with the same approach. To calculate a two-way sum on the Qty column, simply replace COUNTIFS with the SUMIFS function:
=SUMIFS(data[Qty],data[Color],F5#,data[Size],G4#)
Notice the SUMIFS function takes an extra (first) argument, sum_range, which specifies the range to sum. The range/criteria pairs used to target color and size combinations are the same as that used in the COUNTIFS formula. Detailed walkthrough here.
Non-dynamic solution
If you are using an older version of Excel without the UNIQUE function, you can still build a non-dynamic count with the COUNTIFS function. See this video: How to build a simple summary table and this formula.
Dynamic Array Training
Need structured training for dynamic arrays in Excel? See our course: Dynamic Array Formulas.
Download 100+ Important Excel Functions
Get over 100 Excel Functions you should know in one handy PDF.