Written by Allen Wyatt (last updated September 16, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Gerry finds it easiest to put together formulas that use R1C1 cell references. She knows how to do this when manually adding formulas to a worksheet, but wonders how she can use R1C1 references in formulas that she puts together and stuffs into cells using a macro. She wonders if there is anything she needs to watch out for when doing this.
When you are normally stuffing a formula into a cell, you would use this type of syntax in your macro:
Cells(3,1).Formula = "=A1 + A2" Range("A3").Formula = "=A1 + A2"
Either of these will work fine; they both stuff a simple formula into cell A3. If, however, you want to use R1C1 references in the formula you place into cell A3, you only need to change the Formula property to the FormulaR1C1 property:
Cells(3,1).FormulaR1C1 = "=R1C1 + R2C1" Range("A3").FormulaR1C1 = "=R1C1 + R2C1"
It is interesting to note that if you place the above R1C1 formulas into a cell and the worksheet doesn't have R1C1 display turned on, then Excel converts the formula to reflect the display that is active. In other words, it automatically changes "=R1C1 + R2C1" to "=$A$1 + $A$2". The opposite is also true—place the formula "=A1 + A2" into a cell, and it displays as " =R[-2]C + R[-1]C" if you have R1C1 display turned on.
You should also note that since both Formula and FormulaR1C1 are properties, you can read them and see the formula in the cell in the desired format. For instance, let's say cell A3 contains the formula "=A1 + A2". If you then run the following macro, you'll see the formula displayed in the desired formats:
Sub TestFormula() Dim sMsg As String sMsg = "Regular format: " & Cells(3,1).Formula & vbCrLf sMsg = sMsg & "R1C1 format: " & Range("A3").FormulaR1C1 MsgBox sMsg End Sub
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (5294) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
When you need to stop a macro while it is running, you normally press Ctrl+Break. What are you to do if the keypress ...
Discover MoreYou can easily use formulas to pull apart text stored in a cell. For instance, if you need to pull individual characters ...
Discover MoreHow Excel uses templates is different than how Word uses templates. This tip looks at those differences and discusses ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-09-16 10:37:37
J. Woolley
The Tip mentions "...if you have R1C1 display turned on." My Excel Toolbox includes the ToggleRefereceStyle macro (Ctrl+T A 1) to switch between A1 and R1C1. The macro supports Undo (Ctrl+Z). Here is an abbreviated version:
Sub ToggleReferenceStyle()
Const myName As String = "ToggleReferenceStyle"
With Application
.ReferenceStyle = IIf(.ReferenceStyle = xlA1, xlR1C1, xlA1)
.OnUndo myName, (ThisWorkbook.Name + "!" + myName)
End With
End Sub
See https://sites.google.com/view/MyExcelToolbox
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments