Microsoft provides programming examples for illustration only, without warranty either
expressed or implied, including, but not limited to, the implied warranties of
merchantability and/or fitness for a particular purpose. This article assumes
that you are familiar with the programming language being demonstrated and the
tools used to create and debug procedures. Microsoft support professionals can
help explain the functionality of a particular procedure, but they will not
modify these examples to provide added functionality or construct procedures to
meet your specific needs. If you have limited programming experience, you may
want to contact a Microsoft Certified Partner or the Microsoft fee-based
consulting line at (800) 936-5200. For more information about Microsoft Certified
Partners, please visit the following Microsoft Web site:
For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
As an example, suppose you have the following list of names and addresses
on a Microsoft Excel worksheet:
A1: Alice
A2: 123 Anywhere St.
A3: Brian
A4: 234 Indeterminate Lane
A5: Catherine
A6: 345 Unknown Ave.
A7: Dave
A8: 456 Not Sure Blvd.
A9: Erica
A10: 567 Wherever Way
Suppose you want the range B1:B5 to contain links to the names in this
list, but not to the addresses. If you enter "=A1" in cell B1, select the
range B1:B5, and click
Fill Down on the
Edit menu, you will get the following formulas
B1: =A1
B2 =A2
B3: =A3
B4: =A4
B5: =A5
rather than the following formulas
B1: =A1
B2 =A3
B3: =A5
B4: =A7
B5: =A9
which, in this example, would produce the desired result. The following
sample macro enables you to get this result without having to type the
formulas in each cell.
To use the sample macro, first select a vertical range of cells starting
with the cell that contains the formula you want to fill down. In the
example above, you would select the range B1:B5. When you run the macro, a
dialog box will prompt you for the number of cells to increment the
relative references for each cell filled. For the purpose of this example, enter "2".
WARNING: The macro will overwrite any data in the selected range and the <n>-1 cells below it, where <n> is the number you enter in the dialog box.
Sample Visual Basic Procedure
Sub FillAndSkip()
Dim CellToCopy As Range
Dim n As Integer
Dim x As Integer
n = Val(InputBox("Increment relative references by how many cells?"))
Set CellToCopy = Selection.Cells(1)
For x = 2 To Selection.Rows.Count
' COPY the formula to a cell n cells down to update relative
' references.
CellToCopy.Copy
CellToCopy.Offset(n, 0).Range("A1").Select
ActiveSheet.Paste
' CUT and paste to the desired destination so the references don't
' change.
Application.CutCopyMode = False
Selection.Cut
CellToCopy.Offset(1, 0).Range("A1").Select
ActiveSheet.Paste
' Start from the formula just created to get the next formula.
Set CellToCopy = Selection
Next x
End Sub