Increment Relative References by More Than One Cell in VBA (151337)



The information in this article applies to:

  • Microsoft Excel 2000
  • Microsoft Excel 97 for Windows
  • Microsoft Excel for Windows 95
  • Microsoft Excel for Windows 5.0
  • Microsoft Excel 98 Macintosh Edition

This article was previously published under Q151337

SUMMARY

The Fill feature always increments relative references by one for each cell filled. This article shows how to use Microsoft Visual Basic for Applications code to fill a range of cells with a formula and increment the relative references by an amount that you choose.

MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers 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 requirements. 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.
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

  Option Explicit

   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
				

REFERENCES

For additional information about getting help with Visual Basic for Applications, please see the following article in the Microsoft Knowledge Base:

163435 VBA: Programming Resources for Visual Basic for Applications

226118 OFF2000: Programming Resources for Visual Basic for Applications


Modification Type:MinorLast Reviewed:10/11/2006
Keywords:kbdtacode kbhowto kbProgramming KB151337