VB code adjustment to remove fixed references

thomasbeard

Board Regular
Joined
Oct 19, 2005
Messages
139
I have the following VB code that will create a sum formula that will add everything directly to the left:

Activecell.FormulaR1C1 = "=SUM(RC[-1]:" & ActiveCell.End(xlToLeft).Address(ReferenceStyle:=xlR1C1) & ")"

However it comes out in the format:

SUM($A1:E$1)

whereas it needs to be in the format

SUM(A1:E1)

Can someone please help me fix this? Thanks

Tom
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.

cornflakegirl

Well-known Member
Joined
Nov 4, 2004
Messages
2,023
If you add ,RowAbsolute:= False, ColumnAbsolute:=False after the reference style bit, you'll lose your $s. Unfortunately, your formula will also stop working (but only because it isn't really working at the moment - if it were, both $s would be on the same cell reference).

Try:
ActiveCell.FormulaR1C1 = "=SUM(RC[" & ActiveCell.Offset(0, -1).End(xlToLeft).Column - ActiveCell.Column & "]:RC[-1])"
 

RoryA

MrExcel MVP, Moderator
Joined
May 2, 2008
Messages
38,820
Office Version
  1. 365
  2. 2019
  3. 2016
  4. 2010
Platform
  1. Windows
  2. MacOS
You can also use:
Code:
 Activecell.FormulaR1C1 = "=SUM(" & activecell.Offset(0,-1).End(xlToLeft).Address(false, _
false, xlR1C1,false, activecell) & ":RC[-1])"
FWIW.
 

xenou

MrExcel MVP
Joined
Mar 2, 2007
Messages
16,836
Office Version
  1. 2019
Platform
  1. Windows
Another shot:
Code:
Sub Test()
Dim strMyFormula As String
Dim rng As Range

Set rng = Range(ActiveCell.Offset(0, -1), ActiveCell.End(xlToLeft))
strMyFormula = "=SUM(" & rng.Address(RowAbsolute:=False, ColumnAbsolute:=False) & ")"
Debug.Print strMyFormula

ActiveCell.Formula = strMyFormula

End Sub
 

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
24,210
When using R1C1 reference style, the RelativeTo argument needs to be supplied for all relative addresses.
Code:
Activecell.FormulaR1C1 = "=SUM(RC[-1]:" & ActiveCell.End(xlToLeft).Address(False,False,xlR1C1,False,ActiveCell) & ")"
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,164,675
Messages
5,838,716
Members
430,566
Latest member
ChanchalSingh

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top