How to get AUTOSUM into macro?

shajueasow

Well-known Member
Joined
Oct 7, 2004
Messages
1,926
This is the code got while recording a macro to get the total (AutoSum) of numbers in Col A. Since the list is a dynamic one how can it be coded so that it totals all rows with number in it? (All consecutive cells have numbers in them without break. In this case it has numbers till A10, and the total is to be at A11)

Sub gettotal()
Range("A1").Select
Selection.End(xlDown).Select
Range("A11").Select
ActiveCell.FormulaR1C1 = "=SUM(R[-10]C:R[-1]C)"
End Sub

TIA
 

Excel Facts

Links? Where??
If Excel says you have links but you can't find them, go to Formulas, Name Manager. Look for old links to dead workbooks & delete.
Would this do (it will put a total at the bottom of the column of the active cell)?
Code:
Sub gettotal()
Dim Lastrow As Long

Lastrow = Cells(1, ActiveCell.Column).End(xlDown).Row
With ActiveCell
    Cells(Lastrow + 1, .Column).FormulaR1C1 = "=SUM(R[-" & Lastrow & _
        "]C:R[-1]C)"
End With
End Sub
 
Upvote 0
<font face=Courier New><SPAN style="color:#00007F">Sub</SPAN> foo()
<SPAN style="color:#00007F">Dim</SPAN> i <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN>
i = Cells(Rows.Count, "A").End(xlUp).Row
Cells(i + 1, "A") = Application.WorksheetFunction.Sum(Range("A1:A" & i))
<SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN>
</FONT>
 
Upvote 0
Thank You Barrie, That was quick and t just works in the way I want. BUT.......
can this line:
ActiveCell.FormulaR1C1 = "=SUM(R[-10]C:R[-1]C)" be rewritten so that the same the result is obtained. Just to know whether it can be done like this too...
 
Upvote 0
shajueasow said:
Thank You Barrie, That was quick and t just works in the way I want. BUT.......
can this line:
ActiveCell.FormulaR1C1 = "=SUM(R[-10]C:R[-1]C)" be rewritten so that the same the result is obtained. Just to know whether it can be done like this too...

I don't understand what you mean. :unsure: Are you saying you want the SUM formula to be put in the active cell (i.e., you've already selected the last cell)?
 
Upvote 0
Thank You Jon.
Your code gives the value and not the formula.
That approach also was nice.
Thank You very much
 
Upvote 0
I don't know why you wouldn't just use AUTOSUM, but...
Code:
Sub gettotal()
With ActiveCell
    .FormulaR1C1 = "=SUM(R[-" & .Row - 1 & _
        "]C:R[-1]C)"
End With
End Sub
This should be what you want.
 
Upvote 0
<font face=Courier New><SPAN style="color:#00007F">Sub</SPAN> foo()
<SPAN style="color:#00007F">Dim</SPAN> i <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN>, s <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">String</SPAN>
i = Cells(Rows.Count, "A").End(xlUp).Row
s = "=SUM(A1:A" & i & ")"
ActiveCell.Formula = s
<SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN>
</FONT>
 
Upvote 0
Hi Barrie,
I have tried the macro recorder with AUTOSUM, and that was the code given at first itself. But I was really waiting for the "syntax"
R[-" & .Row - 1 & "]C:R[-1]C)" .
Thanks A Lot Barrie.
And Thank you Jon,
as your code can also be used where the last cell is not fixed.
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,208
Members
448,554
Latest member
Gleisner2

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