ID: Q116028
The information in this article applies to:
In Microsoft Excel, you can use the ConvertFormula method in a Visual Basic, Applications Edition, procedure to convert cell references from A1 reference style to R1C1 reference style. This method will also allow you to change from an absolute to a relative reference and vice versa.
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 the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:
http://www.microsoft.com/support/supportnet/refguide/
The following sample Visual Basic procedure uses the ConvertFormula method
to convert A1 relative references to R1C1 absolute references or A1
absolute references to R1C1 relative references for a selected range.
You can also use this procedure to convert cell references between A1 and R1C1 reference style by changing the appropriate constants for "fromReferenceStyle" and "toReferenceStyle" for the ConvertFormula method.
Before running the macro, select one or more cells containing formulas to convert.
'Convert_Reference Type Macro
'A Visual Basic module to convert absolute references to relative
'references or relative references to absolute references.
Sub Conv_RefType()
Dim Conv As String
'Prompt user to change to relative or absolute references
Conv = Application.InputBox _
("Type A to convert to Absolute, R to Relative Reference(s)", _
"Change Cell Reference Type")
'If changing relative to absolute references
If UCase(Conv) = "A" Then
'Loop through each cell selected
For Each Mycell In Selection
If Len(Mycell.Formula) > 0 Then
'Stores cell's formula as variable
MyFormula = Mycell.Formula
'Converts formula to absolute reference style
NewFormula = Application.ConvertFormula _
(Formula:=MyFormula, _
fromReferenceStyle:=xlA1, _
toReferenceStyle:=xlA1, _
toAbsolute:=xlAbsolute)
'Replaces old formula with new absolute formula
Mycell.Formula = NewFormula
End If
Next
'If changing absolute to relative references
ElseIf UCase(Conv) = "R" Then
'Loop through each cell selected
For Each Mycell In Selection
If Len(Mycell.Formula) > 0 Then
'Stores cell's formula as variable
MyFormula = Mycell.Formula
'Converts formula to relative reference style
NewFormula = Application.ConvertFormula _
(Formula:=MyFormula, _
fromReferenceStyle:=xlA1, _
toReferenceStyle:=xlA1, _
toAbsolute:=xlRelative)
'Replaces old formula with new relative formula
Mycell.Formula = NewFormula
End If
Next
'Display Error message if choice entered is invalid
ElseIf UCase(Conv) <> "FALSE" Then
MyMsg = "Enter A for Absolute, R for Relative Reference(s)"
MyTitle = "Option Not Valid"
MyBox = MsgBox(MyMsg, 0, MyTitle)
End If
End Sub
For more information about ConvertFormula, choose Search from the Visual Basic Help menu and type:
ConvertFormula
Additional query words: 97 7.00 5.00 absolute relative howto change XL98
XL97 XL7 XL5
Keywords : kbprg kbdta xlformula KbVBA
Version : WINDOWS:5.0,5.0c,7.0,97
Platform : WINDOWS
Last Reviewed: May 17, 1999