Using the SUM Formula w/ Variable Rows

maize

New Member
Joined
Apr 11, 2011
Messages
12
I'm trying to use the same basic SUM formula down an entire column...

Code:
ActiveSheet.Range("D2").Formula = "=SUM(A2,B2,C2)"

Column D will always be the SUM formula column, but the formula will change to:
ActiveSheet.Range("D3").Formula = "=SUM(A3,B3,C3)"
ActiveSheet.Range("D4").Formula = "=SUM(A4,B4,C4)"
ActiveSheet.Range("D5").Formula = "=SUM(A5,B5,C5)"
ActiveSheet.Range("D6").Formula = "=SUM(A6,B6,C6)"
etc.

Blank rows are included in the spreadsheet and I'd like to be able stop including the SUM formula on the last row with data. Is there an easy way to write this in VBA without having to code in every range?
 

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
Quick and easy would be

Code:
Dim lRow As Long
lRow = Cells(Rows.Count, "A").End(xlUp).Row
Range("D2:D" & lRow).FormulaR1C1 = "=SUM(RC1:RC3)"
Range("A2:A" & lRow).SpecialCells(xlCellTypeBlanks).Offset(, 3).ClearContents

You can remove the last line if you're not bothered about the fomula being in any blank rows between D2 and the last used row.
 
Upvote 0
since the formula will change when you copy it down it isn't necessary to write every line as code. Add the code to copy the formula down to the last row of data
 
Upvote 0

Forum statistics

Threads
1,224,590
Messages
6,179,752
Members
452,940
Latest member
rootytrip

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
Back
Top