Need Help with VBA Code for Sum Formula for Variable Cells

TexasTony

New Member
Joined
Jan 22, 2021
Messages
7
Office Version
  1. 2019
Platform
  1. Windows
Using Excel Office Professional 2019

Using VBA, I need to place a sum formula mirroring autosum on summing a range of variable size.

So in one in instance I am at F16 and need to sum F10:F15. In Another instance I am at F32 and need to sum F24:F31. The cells to sum will be directly above the cell I am in and end with blank row about.

So if I am in F16
F10 - 10
F11 - 5
F12 - 10
F13- 5
F14 - 10
F15 - 20
I need F16 to reflect =sum(F10:F15) and return the value of 60.


However if I am in F32
F24 - 10
F25 -5
F26 - 10
F27 - 5
F28 - 10
F29 - 20
F30 - 10
F31 - 5
I need F32 to reflect =sum(F24:F31) and return the value of 75.

Thanks in advance for any help with this.
 

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
Welcome to the Board!

This macro should do that for you, assuming that you are in the cell you want to put the formula in, like you explained.
VBA Code:
Sub MySum()

    Dim cr As Long
    Dim lr As Long
   
'   Get current row of activecell
    cr = ActiveCell.Row
   
'   Get first row of range
    fr = ActiveCell.Offset(-1, 0).End(xlUp).Row
   
'   Enter sum formula into activecell
    ActiveCell.FormulaR1C1 = "=SUM(R[-" & cr - fr & "]C:R[-1]C)"
   
End Sub
 
Upvote 0
Solution
You are welcome.
Glad I was able to help! :)
 
Upvote 0

Forum statistics

Threads
1,214,979
Messages
6,122,551
Members
449,088
Latest member
davidcom

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