Incrementing Relative References in Formulas by More Than One (152265)
The information in this article applies to:
- Microsoft Excel 97 for Windows
- Microsoft Excel for Windows 95
- Microsoft Excel for Windows 5.0
- Microsoft Excel 98 Macintosh Edition
- Microsoft Excel for Windows 95 7.0a
- Microsoft Excel for Windows 5.0c
- Microsoft Excel for Windows NT 5.0
- Microsoft Excel for the Macintosh 5.0
- Microsoft Excel for the Macintosh 5.0a
This article was previously published under Q152265 SUMMARY
When you fill formulas down a column or across a row, the relative
references are, by default, incremented by one. The formulas can be
altered so that they are incremented by a user-defined amount through the
use of the OFFSET function.
MORE INFORMATION
The formula for incrementing by more than a row is:
=OFFSET(<Starting_Cell>,(ROW()-<Current_Row>)*<Inc>,0)
where <Starting_Cell> is the absolute reference to the first cell in the
range of interest, <Current_Row> is the row of the cell in which the
formula is being entered, and <Inc> is the number of rows to increment.
The formula for incrementing by more than column is:
=OFFSET(<Starting_Cell>,0,(COLUMN()-<Current_Column>)*<Inc>)
where <Starting_Cell> is the absolute reference to the first cell in the
range of interest, <Current_Column> is the number associated with the
column of the cell in which the formula is being entered, and <Inc> is the
number of columns to increment.
Example Incrementing a Formula by More Than One Row- Type the following information in a worksheet:
A1: Patrick B1:
A2: 79 B2:
A3: Ricky B3:
A4: 68 B4:
A5: Matt B5:
A6: 23 B6:
A7: John B7:
A8: 15 B8:
A9: Mary B9:
A10: 40 B10: - Type the following formula in cell B1:
B1: =OFFSET($A$2,(ROW()-1)*2,0) - With cell B1 selected, grab the fill handle and fill down the formula
through cell B5. The resulting cells will look as follows:
B1: 79
B2: 68
B3: 23
B4: 15
B5: 40
Example Incrementing a Formula by More Than One Column- Type the following information in a worksheet:
A1: Patrick B1: 79 C1: Ricky D1: 68 E1: Matt F1: 23
A2: B2: C2: D2: E2: F2: - Type the following formula in cell A2:
A2: =OFFSET($B$1,0,(COLUMN()-1)*2)
- With cell A2 selected, grab the fill handle and fill the formula right
through cell C2:
Example Using ISEVEN Function
This formula is not restricted to extracting data. It can also be used
within other formulas. By using the following formula, you can test if the
numerical data in every fourth row is even:
=IF(ISEVEN(OFFSET(<Starting_Cell>,(ROW()-<Current_Row>)*<Inc>,0),
"EVEN","ODD")
where <Starting_Cell> is the absolute reference to the first cell in the
range of interest, <Current_Row> is the row of the cell in which the
formula is being entered, and <Inc> is the number of rows to increment.
NOTE: This formula requires that the Analysis ToolPack is included in the
Add-Ins. To do this, on the Tools menu, click Add-Ins and click to select
the check in the box next to Analysis ToolPack.
- Type the following information in a worksheet:
A1: Patrick B1:
A2: 79 B2:
A3: Ricky B3:
A4: 68 B4:
A5: Matt B5:
A6: 23 B6:
A7: John B7:
A8: 15 B8:
A9: Mary B9:
A10: 40 B10: - Type the following formula in cell B1:
B1: =IF(ISEVEN(OFFSET($A$2,(ROW()-1)*4,0)),"EVEN","ODD") - With cell B1 selected, grab the fill handle and fill down the formula
through cell B3. The resulting cells will look as follows:
For additional information, please see the following article(s) in the
Microsoft Knowledge Base:
151337
Incrementing Relative References by More Than One Cell in
VBA
Modification Type: | Minor | Last Reviewed: | 8/17/2005 |
---|
Keywords: | kbhowto kbualink97 KB152265 |
---|
|