You can use the SUBTOTAL function to dynamically count or display other information about records in a list that has AutoFilter turned on. When you change the AutoFilter criteria, the results of the SUBTOTAL function also change.
Count the Total Number of Filtered Records
To determine the total number of filtered records that the AutoFilter feature returns, use the SUBTOTAL function with the following two arguments:
=SUBTOTAL(function_num,ref)
- Function_num corresponds to the number of the function that you use to calculate the subtotal:
1 AVERAGE 2 COUNT 3 COUNTA 4 MAX 5 MIN 6 PRODUCT 7 STDEV 8 STDEVP 9 SUM 10 VAR 11 VARP
- Ref is the cell range that you want to subtotal.
Count Records in a Filtered List
The following example illustrates how to use the SUBTOTAL function to count records in a filtered list:- Type the following data in a new, blank worksheet:
A1: Animal B1: In Stock C1: Price A2: Dog B2: 1 C2: $1.00 A3: Cat B3: 2 C3: $2.00 A4: Dog B4: 3 C4: $3.00 A5: Cat B5: 4 C5: $4.00 A6: Bird B6: 5 C6: $5.00
- On the Data menu, point to Filter, and then click AutoFilter.
Excel turns on the AutoFilter, and places a drop-down arrow next to each field (column heading). - In cell C8, type the following formula:=SUBTOTAL(3,C2:C6)
- Click the arrow for the Animal field, and then click Cat.
The AutoFilter displays all the records that contain Cat in the Animal field. Because two records are now displayed, the subtotal value in cell C8 is 2. - Click the arrow for the Animal field, and then click Bird.
The AutoFilter displays all the records that contain Bird in the Animal field. Because one record is now displayed, the subtotal value in cell C8 is now 1.