The INDEX function returns a value or the reference to a value from within a table or range.
There are two ways to use the INDEX function:
-
If you want to return the value of a specified cell or array of cells, see Array form.
-
If you want to return a reference to specified cells, see Reference form.
Array form
Description
Returns the value of an element in a table or an array, selected by the row and column number indexes.
Use the array form if the first argument to INDEX is an array constant.
Syntax
INDEX(array, row_num, [column_num])
The array form of the INDEX function has the following arguments:
-
array Required. A range of cells or an array constant.
-
If array contains only one row or column, the corresponding row_num or column_num argument is optional.
-
If array has more than one row and more than one column, and only row_num or column_num is used, INDEX returns an array of the entire row or column in array.
-
-
row_num Required, unless column_num is present. Selects the row in array from which to return a value. If row_num is omitted, column_num is required.
-
column_num Optional. Selects the column in array from which to return a value. If column_num is omitted, row_num is required.
Remarks
-
If both the row_num and column_num arguments are used, INDEX returns the value in the cell at the intersection of row_num and column_num.
-
row_num and column_num must point to a cell within array; otherwise, INDEX returns a #REF! error.
-
If you set row_num or column_num to 0 (zero), INDEX returns the array of values for the entire column or row, respectively. To use values returned as an array, enter the INDEX function as an array formula.
: If you have a current version of Microsoft 365, then you can input the formula in the top-left-cell of the output range, then press ENTER to confirm the formula as a dynamic array formula. Otherwise, the formula must be entered as a legacy array formula by first selecting the output range, input the formula in the top-left-cell of the output range, then press CTRL+SHIFT+ENTER to confirm it. Excel inserts curly brackets at the beginning and end of the formula for you. For more information on array formulas, see Guidelines and examples of array formulas.
Examples
Example 1
These examples use the INDEX function to find the value in the intersecting cell where a row and a column meet.
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.
Data |
Data |
|
---|---|---|
Apples |
Lemons |
|
Bananas |
Pears |
|
Formula |
Description |
Result |
=INDEX(A2:B3,2,2) |
Value at the intersection of the second row and second column in the range A2:B3. |
Pears |
=INDEX(A2:B3,2,1) |
Value at the intersection of the second row and first column in the range A2:B3. |
Bananas |
Example 2
This example uses the INDEX function in an array formula to find the values in two cells specified in a 2x2 array.
: If you have a current version of Microsoft 365, then you can input the formula in the top-left-cell of the output range, then press ENTER to confirm the formula as a dynamic array formula. Otherwise, the formula must be entered as a legacy array formula by first selecting two blank cells, input the formula in the top-left-cell of the output range, then press CTRL+SHIFT+ENTER to confirm it. Excel inserts curly brackets at the beginning and end of the formula for you. For more information on array formulas, see Guidelines and examples of array formulas.
Formula |
Description |
Result |
---|---|---|
=INDEX({1,2;3,4},0,2) |
Value found in the first row, second column in the array. The array contains 1 and 2 in the first row and 3 and 4 in the second row. |
2 |
Value found in the second row, second column in the array (same array as above). |
4 |
|
Reference form
Description
Returns the reference of the cell at the intersection of a particular row and column. If the reference is made up of non-adjacent selections, you can pick the selection to look in.
Syntax
INDEX(reference, row_num, [column_num], [area_num])
The reference form of the INDEX function has the following arguments:
-
reference Required. A reference to one or more cell ranges.
-
If you are entering a non-adjacent range for the reference, enclose reference in parentheses.
-
If each area in reference contains only one row or column, the row_num or column_num argument, respectively, is optional. For example, for a single row reference, use INDEX(reference,,column_num).
-
-
row_num Required. The number of the row in reference from which to return a reference.
-
column_num Optional. The number of the column in reference from which to return a reference.
-
area_num Optional. Selects a range in reference from which to return the intersection of row_num and column_num. The first area selected or entered is numbered 1, the second is 2, and so on. If area_num is omitted, INDEX uses area 1. The areas listed here must all be located on one sheet. If you specify areas that are not on the same sheet as each other, it will cause a #VALUE! error. If you need to use ranges that are located on different sheets from each other, it is recommended that you use the array form of the INDEX function, and use another function to calculate the range that makes up the array. For example, you could use the CHOOSE function to calculate which range will be used.
For example, if Reference describes the cells (A1:B4,D1:E4,G1:H4), area_num 1 is the range A1:B4, area_num 2 is the range D1:E4, and area_num 3 is the range G1:H4.
Remarks
-
After reference and area_num have selected a particular range, row_num and column_num select a particular cell: row_num 1 is the first row in the range, column_num 1 is the first column, and so on. The reference returned by INDEX is the intersection of row_num and column_num.
-
If you set row_num or column_num to 0 (zero), INDEX returns the reference for the entire column or row, respectively.
-
row_num, column_num, and area_num must point to a cell within reference; otherwise, INDEX returns a #REF! error. If row_num and column_num are omitted, INDEX returns the area in reference specified by area_num.
-
The result of the INDEX function is a reference and is interpreted as such by other formulas. Depending on the formula, the return value of INDEX may be used as a reference or as a value. For example, the formula CELL("width",INDEX(A1:B2,1,2)) is equivalent to CELL("width",B1). The CELL function uses the return value of INDEX as a cell reference. On the other hand, a formula such as 2*INDEX(A1:B2,1,2) translates the return value of INDEX into the number in cell B1.
Examples
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.
Fruit |
Price |
Count |
---|---|---|
Apples |
$0.69 |
40 |
Bananas |
$0.34 |
38 |
Lemons |
$0.55 |
15 |
Oranges |
$0.25 |
25 |
Pears |
$0.59 |
40 |
Almonds |
$2.80 |
10 |
Cashews |
$3.55 |
16 |
Peanuts |
$1.25 |
20 |
Walnuts |
$1.75 |
12 |
Formula |
Description |
Result |
=INDEX(A2:C6, 2, 3) |
The intersection of the second row and third column in the range A2:C6, which is the contents of cell C3. |
38 |
=INDEX((A1:C6, A8:C11), 2, 2, 2) |
The intersection of the second row and second column in the second area of A8:C11, which is the contents of cell B9. |
1.25 |
=SUM(INDEX(A1:C11, 0, 3, 1)) |
The sum of the third column in the first area of the range A1:C11, which is the sum of C1:C11. |
216 |
=SUM(B2:INDEX(A2:C6, 5, 2)) |
The sum of the range starting at B2, and ending at the intersection of the fifth row and the second column of the range A2:A6, which is the sum of B2:B6. |
2.42 |