This article describes the formula syntax and usage of the SUBTOTAL function in Microsoft Excel.
Description
Returns a subtotal in a list or database. It is generally easier to create a list with subtotals by using the Subtotal command in the Outline group on the Data tab in the Excel desktop application. Once the subtotal list is created, you can modify it by editing the SUBTOTAL function.
Syntax
SUBTOTAL(function_num,ref1,[ref2],...)
The SUBTOTAL function syntax has the following arguments:
-
Function_num Required. The number 1-11 or 101-111 that specifies the function to use for the subtotal. 1-11 includes manually-hidden rows, while 101-111 excludes them; filtered-out cells are always excluded.
Function_num (includes hidden rows) |
Function_num (ignores hidden rows) |
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 |
-
Ref1 Required. The first named range or reference for which you want the subtotal.
-
Ref2,... Optional. Named ranges or references 2 to 254 for which you want the subtotal.
Remarks
-
If there are other subtotals within ref1, ref2,… (or nested subtotals), these nested subtotals are ignored to avoid double counting.
-
For the function_num constants from 1 to 11, the SUBTOTAL function includes the values of rows hidden by the Hide Rows command under the Hide & Unhide submenu of the Format command in the Cells group on the Home tab in the Excel desktop application. Use these constants when you want to subtotal hidden and nonhidden numbers in a list. For the function_Num constants from 101 to 111, the SUBTOTAL function ignores values of rows hidden by the Hide Rows command. Use these constants when you want to subtotal only nonhidden numbers in a list.
-
The SUBTOTAL function ignores any rows that are not included in the result of a filter, no matter which function_num value you use.
-
The SUBTOTAL function is designed for columns of data, or vertical ranges. It is not designed for rows of data, or horizontal ranges. For example, when you subtotal a horizontal range using a function_num of 101 or greater, such as SUBTOTAL(109,B2:G2), hiding a column does not affect the subtotal. But, hiding a row in a subtotal of a vertical range does affect the subtotal.
-
If any of the references are 3-D references, SUBTOTAL returns the #VALUE! error value.
Example
Copy the example data in the following table, and paste it in cell A1 of a new Excel worksheet. For formulas to show results, select them, press F2, and then press Enter. If you need to, you can adjust the column widths to see all the data.
Data |
||
---|---|---|
120 |
||
10 |
||
150 |
||
23 |
||
Formula |
Description |
Result |
=SUBTOTAL(9,A2:A5) |
The sum of the subtotal of the cells A2:A5, using 9 as the first argument. |
303 |
=SUBTOTAL(1,A2:A5) |
The average of the subtotal of the cells A2:A5, using 1 as the first argument. |
75.75 |
Notes |
||
The SUBTOTAL function always requires a numeric argument (1 through 11, 101 through 111) as its first argument. This numeric argument is applied to the subtotal of the values (cell ranges, named ranges) that are specified as the arguments that follow. |