INDEX function

Description

Returns a value or the reference to a value from within a table or range. There are two forms of the INDEX function: the array form and the reference form.

If you want to

Then see

Return the value of a specified cell or array of cells

Array form

Return a reference to specified cells

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 INDEX function syntax 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. 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.

  • 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 in a horizontal range of cells for a row, and in a vertical range of cells for a column. To enter an array formula, press CTRL+SHIFT+ENTER.

    Note    In Excel Web App, you cannot create array formulas.

  • Row_num and Column_num must point to a cell within array; otherwise, INDEX returns the #REF! error value.

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. If you need to, you can adjust the column widths to see all the data.

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.

=INDEX(A2:B3,2,2)

'=INDEX(A2:B3,2,1)

Value at the intersection of the second row and first column in the range A2:B3.

=INDEX(A2:B3,2,1)

Example 2

This example uses the INDEX function in an array formula to find the values in two cells specified in a 2x2 array.

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.

=INDEX({1,2;3,4},0,2)

Value found in the second row, second column in the array (same array as above).

=INDEX({1,2;3,4},0,2)

Note   The formula in cell C2 is an array formula. For this formula to return values in cells C2 and C3, select C2 and C3, press F2, and then press CTRL+Shift+Enter. Otherwise, only a value in cell C2 will be returned.

Top of Page

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 nonadjacent selections, you can pick the selection to look in.

Syntax

INDEX(reference, row_num, [column_num], [area_num])

The INDEX function syntax has the following arguments.

  • Reference    Required. A reference to one or more cell ranges.

    • If you are entering a nonadjacent 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.

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 the #REF! error value. 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.

Note    The CELL function is not available in Excel Web App.

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. If you need to, you can adjust the column widths to see all the data.

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.

3.55

=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:C6.

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

Top of Page

Applies To: Excel 2013, Excel 2007, Excel 2010, Excel Starter, Excel Online, Excel 2016 for Mac



Was this information helpful?

Yes No

How can we improve it?

255 characters remaining

To protect your privacy, please do not include contact information in your feedback. Review our privacy policy.

Thank you for your feedback!

Support resources

Change language