How to use the SUBTOTAL function
What is the SUBTOTAL function?
The SUBTOTAL function calculates a subtotal based on a cell range.
The picture above shows row 4 and row 8 hidden, the SUM argument 9 sums all values in C3:C11 whereas argument 109 ignores hidden values. That is why you see different sums in cell B14 and B15.
Table of Contents
- Syntax
- Arguments
- Does the SUBTOTAL function avoid double counting?
- How to include manually hidden values in the SUBTOTAL function?
- How to exclude manually hidden values from the SUBTOTAL function?
- How to sum filtered data?
- How to count the number of cells containing numbers based on filtered data?
- How to count the number of not empty cells based on filtered data?
- How to extract the largest number from filtered data?
- How to extract the smallest number from filtered data?
- How to calculate an average based on filtered data?
- Extract filtered values - Excel 365
- Function not working
- Get Excel file
1. Syntax
SUBTOTAL(function_num, ref1, ...)
The function returns a subtotal from a list or database, you can choose from a variety of arguments that determine what you want the function to do.
The SUBTOTAL function allows you to have up to 254 cell ranges.
2. Arguments
Filtered-out cells from Excel Tables and Excel feature "Filter" are always excluded.
Function_num (includes hidden values) |
Function_num (ignores hidden values) |
Function |
1 | 101 | AVERAGE |
2 | 102 | COUNT |
3 | 103 | COUNTA |
4 | 104 | MAX |
5 | 105 | MIN |
6 | 106 | PRODUCT |
7 | 107 | STDEV |
8 | 108 | STDEVP |
9 | 109 | SUM |
10 | 110 | VAR |
11 | 111 | VARP |
To clarify, hidden values are manually hidden values. Filtered-out values are not manually hidden values.
3. Does the SUBTOTAL function avoid double counting?
Yes, other SUBTOTAL formulas in your cell range are ignored to avoid double counting.
4. How to include manually hidden values in the SUBTOTAL function?
Use function_num between 1 and 11 to include manually hidden values to the SUBTOTAL function.
Formula in cell C11:
Rows 4 and 8 are hidden. The total is 38: 9 + 7 + 3 + 5 + 2 + 2 + 10 = 38.
Cell C4 contains 7 and cell C8 contains 2. The first argument is 9 which is between 1 and 11 meaning manually hidden cells are included.
5. How to exclude manually hidden values from the SUBTOTAL function?
Use function_num between 101 and 111 to exclude manually hidden values to the SUBTOTAL function.
Formula in cell C11:
The formula in cell C11 excludes manually hidden values in the SUBTOTAL calculation. Rows 2 and 8 are manually hidden.
9 + 3 + 5 + 2 + 10 equals 29.
6. How to sum filtered data?
The image above demonstrates a formula that adds number and returns a total based on filtered values.
I have applied "Filter" to cell range B2:C9, the buttons next to the column header names show that you can apply a filter. The data table has rows 5 and 6 filtered out.
Formula in cell C11:
The first argument is 9 which represents the SUM function, it adds numbers and returns a total.
9 + 7 + 2 + 2 + 10 equals 30 which is all visible numbers in cell range C3:C9.
7. How to count the number of cells containing numbers based on filtered data?
The image above demonstrates a formula in cell C11 that counts the number of numbers based on filtered values in a given cell range.
Cell range C3:C9 contains both numbers and letters and is filtered. Cells C5, C6, and C7 are filtered out.
Formula in cell C11:
The COUNT function counts the number of numbers in a given cell range. There are two visible numbers in cell range C3:C9.
8. How to count the number of not empty cells based on filtered data?
The image above shows a filtered data set in cell range B3:C9, it has a few empty cells. The formula in cell C11 counts not empty cells based on the filtered data.
Formula in cell C11:
The first argument is 3 which represents the COUNTA function, it counts not empty cells.
Rows 3 and 4 are filtered out. Cells C5, C7, and C9 are not empty. The formula returns 3.
9. How to extract the largest number from filtered data?
The picture above shows filtered data in cell range B3:C9, the formula in cell C11 extracts the largest number from the filtered cells.
Formula in cell C11:
The first argument is 4 which represents the MAX function, it extracts the largest number.
10. How to extract the smallest number from filtered data?
The image above shows filtered data in cell range B3:C9, the formula in cell C11 extracts the smallest number from the visible cells.
Formula in cell C11:
The first argument is 5 which represents the MIN function, it extracts the largest number.
11. How to calculate an average based on filtered data?
The image above shows filtered data in cell range B3:C9, the formula in cell C11 calculates the average number based on the visible cells in cell range C3:C9.
Formula in cell C11:
The first argument is 1 which represents the AVERAGE function, it calculates the average based on a group of numbers.
9 + 7 + 2 + 10 = 28. 28/4 = 7.
12. Extract filtered values - Excel 365
The image above shows an Excel 365 formula in cell C11 that extracts filtered values from cell range C3:C9.
Formula in cell C11:
Explaining formula in cell C11
Step 1 - Calculate rows in cell range
The ROWS function calculates the number of rows a cell range contains.
ROWS(B3:B9)
returns 7. Cell range B3:B9 contains seven rows.
Step 2 - Create a sequence from 0 (zero) to n
The SEQUENCE function creates a list of sequential numbers to a cell range or array. It is only available to Excel 365 subscribers.
SEQUENCE(rows, [columns], [start], [step])
SEQUENCE(ROWS(B3:B9), , 0)
becomes
SEQUENCE(7, , 0)
and returns {0; 1; 2; 3; 4; 5; 6}.
Step 3 - Workaround for finding filtered values
The OFFSET function returns a reference to a range that is a given number of rows and columns from a given reference.
OFFSET(reference, rows, columns, [height], [width])
OFFSET(C3, SEQUENCE(ROWS(B3:B9), , 0), 0, 1)
becomes
OFFSET(C3, {0; 1; 2; 3; 4; 5; 6}, 0, 1)
and returns {9; 7; 3; 5; 2; 2; 10}.
Step 4 - Identify visible cells
SUBTOTAL(3, OFFSET(C3, SEQUENCE(ROWS(B3:B9), , 0), 0, 1))
becomes
SUBTOTAL(3, {9; 7; 3; 5; 2; 2; 10})
and returns {0; 1; 1; 0; 1; 1; 0}. 1 indicates a filtered value and 0 (zero) a hidden value.
Step 5 - Extract values
The FILTER function lets you extract values/rows based on a condition or criteria.
FILTER(array, include, [if_empty])
FILTER(C3:C9, SUBTOTAL(3, OFFSET(C3, SEQUENCE(ROWS(B3:B9), , 0), 0, 1)))
becomes
FILTER(C3:C9, {0; 1; 1; 0; 1; 1; 0})
becomes
FILTER({9; 7; 3; 5; 2; 2; 10}, {0; 1; 1; 0; 1; 1; 0})
and returns {7; 3; 2; 2}.
13. Function not working
The SUBTOTAL function returns
- #VALUE! error if you use a non-numeric input value in the first argument function_num.
- #NAME? error if you misspell the function name.
- propagates errors, meaning that if the input contains an error (e.g., #VALUE!, #REF!), the function will return the same error.
13.1 Troubleshooting the error value
When you encounter an error value in a cell a warning symbol appears, displayed in the image above. Press with mouse on it to see a pop-up menu that lets you get more information about the error.
- The first line describes the error if you press with left mouse button on it.
- The second line opens a pane that explains the error in greater detail.
- The third line takes you to the "Evaluate Formula" tool, a dialog box appears allowing you to examine the formula in greater detail.
- This line lets you ignore the error value meaning the warning icon disappears, however, the error is still in the cell.
- The fifth line lets you edit the formula in the Formula bar.
- The sixth line opens the Excel settings so you can adjust the Error Checking Options.
Here are a few of the most common Excel errors you may encounter.
#NULL error - This error occurs most often if you by mistake use a space character in a formula where it shouldn't be. Excel interprets a space character as an intersection operator. If the ranges don't intersect an #NULL error is returned. The #NULL! error occurs when a formula attempts to calculate the intersection of two ranges that do not actually intersect. This can happen when the wrong range operator is used in the formula, or when the intersection operator (represented by a space character) is used between two ranges that do not overlap. To fix this error double check that the ranges referenced in the formula that use the intersection operator actually have cells in common.
#SPILL error - The #SPILL! error occurs only in version Excel 365 and is caused by a dynamic array being to large, meaning there are cells below and/or to the right that are not empty. This prevents the dynamic array formula expanding into new empty cells.
#DIV/0 error - This error happens if you try to divide a number by 0 (zero) or a value that equates to zero which is not possible mathematically.
#VALUE error - The #VALUE error occurs when a formula has a value that is of the wrong data type. Such as text where a number is expected or when dates are evaluated as text.
#REF error - The #REF error happens when a cell reference is invalid. This can happen if a cell is deleted that is referenced by a formula.
#NAME error - The #NAME error happens if you misspelled a function or a named range.
#NUM error - The #NUM error shows up when you try to use invalid numeric values in formulas, like square root of a negative number.
#N/A error - The #N/A error happens when a value is not available for a formula or found in a given cell range, for example in the VLOOKUP or MATCH functions.
#GETTING_DATA error - The #GETTING_DATA error shows while external sources are loading, this can indicate a delay in fetching the data or that the external source is unavailable right now.
13.2 The formula returns an unexpected value
To understand why a formula returns an unexpected value we need to examine the calculations steps in detail. Luckily, Excel has a tool that is really handy in these situations. Here is how to troubleshoot a formula:
- Select the cell containing the formula you want to examine in detail.
- Go to tab “Formulas” on the ribbon.
- Press with left mouse button on "Evaluate Formula" button. A dialog box appears.
The formula appears in a white field inside the dialog box. Underlined expressions are calculations being processed in the next step. The italicized expression is the most recent result. The buttons at the bottom of the dialog box allows you to evaluate the formula in smaller calculations which you control. - Press with left mouse button on the "Evaluate" button located at the bottom of the dialog box to process the underlined expression.
- Repeat pressing the "Evaluate" button until you have seen all calculations step by step. This allows you to examine the formula in greater detail and hopefully find the culprit.
- Press "Close" button to dismiss the dialog box.
There is also another way to debug formulas using the function key F9. F9 is especially useful if you have a feeling that a specific part of the formula is the issue, this makes it faster than the "Evaluate Formula" tool since you don't need to go through all calculations to find the issue..
- Enter Edit mode: Double-press with left mouse button on the cell or press F2 to enter Edit mode for the formula.
- Select part of the formula: Highlight the specific part of the formula you want to evaluate. You can select and evaluate any part of the formula that could work as a standalone formula.
- Press F9: This will calculate and display the result of just that selected portion.
- Evaluate step-by-step: You can select and evaluate different parts of the formula to see intermediate results.
- Check for errors: This allows you to pinpoint which part of a complex formula may be causing an error.
The image above shows cell reference C11 converted to hard-coded value using the F9 key. The SUBTOTAL function requires numerical values in the first argument which is not the case in this example. We have found what is wrong with the formula.
Tips!
- View actual values: Selecting a cell reference and pressing F9 will show the actual values in those cells.
- Exit safely: Press Esc to exit Edit mode without changing the formula. Don't press Enter, as that would replace the formula part with the calculated value.
- Full recalculation: Pressing F9 outside of Edit mode will recalculate all formulas in the workbook.
Remember to be careful not to accidentally overwrite parts of your formula when using F9. Always exit with Esc rather than Enter to preserve the original formula. However, if you make a mistake overwriting the formula it is not the end of the world. You can “undo” the action by pressing keyboard shortcut keys CTRL + z or pressing the “Undo” button
13.3 Other errors
Floating-point arithmetic may give inaccurate results in Excel - Article
Floating-point errors are usually very small, often beyond the 15th decimal place, and in most cases don't affect calculations significantly.
Useful links
SUBTOTAL function - Microsoft
SUBTOTAL function - Contextures
'SUBTOTAL' function examples
This article explains how to count cells highlighted with Conditional Formatting (CF). The image above shows data in cell range […]
This article demonstrates two formulas that extract distinct values from a filtered Excel Table, one formula for Excel 365 subscribers […]
This article demonstrates formulas and Excel tools that extract duplicates based on three conditions. The first and second condition is […]
Functions in 'Math and trigonometry' category
The SUBTOTAL function function is one of 62 functions in the 'Math and trigonometry' category.
Excel function categories
Excel categories
One Response to “How to use the SUBTOTAL function”
Leave a Reply
How to comment
How to add a formula to your comment
<code>Insert your formula here.</code>
Convert less than and larger than signs
Use html character entities instead of less than and larger than signs.
< becomes < and > becomes >
How to add VBA code to your comment
[vb 1="vbnet" language=","]
Put your VBA code here.
[/vb]
How to add a picture to your comment:
Upload picture to postimage.org or imgur
Paste image link to your comment.
Contact Oscar
You can contact me through this contact form
I've been looking for a long time how to use the subtotal formula. Thanks for your helpful blog.