VBA code to calculate column totals

kevinh2320

Board Regular
Joined
May 13, 2016
Messages
61
Column I of my worksheet is titled AMT_OWED. What I am trying to do is loop through this column and total each group of AMT_OWED rows individually. In the example below there are 3 groups that need to be totaled. Example A is what my spreadsheet looks like now (no totals for each group). Example B shows what I'd like to achieve. I've bolded the totals for emphasis. This report is run frequently and the numbers of rows for each group will vary in number of rows so code will need to account for that. Any help would be greatly appreciated.

[TABLE="width: 500"]
<tbody>[TR]
[TD]Example A[/TD]
[TD][/TD]
[TD]Example B[/TD]
[/TR]
[TR]
[TD][TABLE="width: 83"]
<tbody>[TR]
[TD]AMT_OWED[/TD]
[/TR]
[TR]
[TD="align: right"]5,410.80[/TD]
[/TR]
[TR]
[TD="align: right"]2,827.02[/TD]
[/TR]
[TR]
[TD="align: right"]2,523.86[/TD]
[/TR]
[TR]
[TD="align: right"]557.96[/TD]
[/TR]
[TR]
[TD="align: right"]1,195.00[/TD]
[/TR]
[TR]
[TD="align: right"]1,219.36[/TD]
[/TR]
[TR]
[TD="align: right"]60.31[/TD]
[/TR]
[TR]
[TD="align: right"]82.86[/TD]
[/TR]
[TR]
[TD="align: right"]13,485.62[/TD]
[/TR]
[TR]
[TD="align: right"]800.00[/TD]
[/TR]
[TR]
[TD="align: right"]7,924.38[/TD]
[/TR]
[TR]
[TD="align: right"]8,037.00[/TD]
[/TR]
[TR]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[/TR]
[TR]
[TD]AMT_OWED[/TD]
[/TR]
[TR]
[TD="align: right"]1,053.56[/TD]
[/TR]
[TR]
[TD="align: right"]25.00[/TD]
[/TR]
[TR]
[TD="align: right"]2,681.77[/TD]
[/TR]
[TR]
[TD="align: right"]7,708.38[/TD]
[/TR]
[TR]
[TD="align: right"]67.31[/TD]
[/TR]
[TR]
[TD="align: right"]5,000.00[/TD]
[/TR]
[TR]
[TD="align: right"]1,594.81[/TD]
[/TR]
[TR]
[TD="align: right"]67.31[/TD]
[/TR]
[TR]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[/TR]
[TR]
[TD]AMT_OWED[/TD]
[/TR]
[TR]
[TD="align: right"]1,000.00[/TD]
[/TR]
[TR]
[TD="align: right"]3,495.00[/TD]
[/TR]
[TR]
[TD="align: right"]3,000.00[/TD]
[/TR]
[TR]
[TD="align: right"]1,000.00[/TD]
[/TR]
[TR]
[TD="align: right"]1,025.00[/TD]
[/TR]
[TR]
[TD="align: right"]696.00[/TD]
[/TR]
[TR]
[TD="align: right"]3,041.42[/TD]
[/TR]
[TR]
[TD="align: right"]1,000.00[/TD]
[/TR]
[TR]
[TD="align: right"]251.00[/TD]
[/TR]
[TR]
[TD="align: right"]6,500.00[/TD]
[/TR]
[TR]
[TD="align: right"]250.00[/TD]
[/TR]
[TR]
[TD="align: right"]1,227.13[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][/TD]
[TD][TABLE="width: 83"]
<tbody>[TR]
[TD]AMT_OWED[/TD]
[/TR]
[TR]
[TD="align: right"]5,410.80[/TD]
[/TR]
[TR]
[TD="align: right"]2,827.02[/TD]
[/TR]
[TR]
[TD="align: right"]2,523.86[/TD]
[/TR]
[TR]
[TD="align: right"]557.96[/TD]
[/TR]
[TR]
[TD="align: right"]1,195.00[/TD]
[/TR]
[TR]
[TD="align: right"]1,219.36[/TD]
[/TR]
[TR]
[TD="align: right"]60.31[/TD]
[/TR]
[TR]
[TD="align: right"]82.86[/TD]
[/TR]
[TR]
[TD="align: right"]13,485.62[/TD]
[/TR]
[TR]
[TD="align: right"]800.00[/TD]
[/TR]
[TR]
[TD="align: right"]7,924.38[/TD]
[/TR]
[TR]
[TD="align: right"]8,037.00[/TD]
[/TR]
[TR]
[TD="align: right"]44,124.17[/TD]
[/TR]
[TR]
[TD][/TD]
[/TR]
[TR]
[TD]AMT_OWED[/TD]
[/TR]
[TR]
[TD="align: right"]1,053.56[/TD]
[/TR]
[TR]
[TD="align: right"]25.00[/TD]
[/TR]
[TR]
[TD="align: right"]2,681.77[/TD]
[/TR]
[TR]
[TD="align: right"]7,708.38[/TD]
[/TR]
[TR]
[TD="align: right"]67.31[/TD]
[/TR]
[TR]
[TD="align: right"]5,000.00[/TD]
[/TR]
[TR]
[TD="align: right"]1,594.81[/TD]
[/TR]
[TR]
[TD="align: right"]67.31[/TD]
[/TR]
[TR]
[TD="align: right"]18,198.14[/TD]
[/TR]
[TR]
[TD][/TD]
[/TR]
[TR]
[TD]AMT_OWED[/TD]
[/TR]
[TR]
[TD="align: right"]1,000.00[/TD]
[/TR]
[TR]
[TD="align: right"]3,495.00[/TD]
[/TR]
[TR]
[TD="align: right"]3,000.00[/TD]
[/TR]
[TR]
[TD="align: right"]1,000.00[/TD]
[/TR]
[TR]
[TD="align: right"]1,025.00[/TD]
[/TR]
[TR]
[TD="align: right"]696.00[/TD]
[/TR]
[TR]
[TD="align: right"]3,041.42[/TD]
[/TR]
[TR]
[TD="align: right"]1,000.00[/TD]
[/TR]
[TR]
[TD="align: right"]251.00[/TD]
[/TR]
[TR]
[TD="align: right"]6,500.00[/TD]
[/TR]
[TR]
[TD="align: right"]250.00[/TD]
[/TR]
[TR]
[TD="align: right"]1,227.13[/TD]
[/TR]
[TR]
[TD="align: right"]22,485.55[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
Re: help with vba code to calculate column totals

A few questions
1) Will there always be a blank row between groups?
2) Are the numbers hard values, or formulae?
3) Do you just want the sum value returned, or do you want a formula in there?
 
Upvote 0
Re: help with vba code to calculate column totals

Assuming the answers are
1) Yes
2) hard values
3) formula

Try
Code:
Sub kevinh2320()
   Dim Rng As Range
   For Each Rng In Range("I:I").SpecialCells(xlConstants).Areas
      Rng.Offset(Rng.Count)(1).Formula = "=sum(" & Rng.Address & ")"
   Next Rng
End Sub
Easily changed if any assumptions are wrong :)
 
Last edited:
Upvote 0
Re: help with vba code to calculate column totals

That works perfectly! Thank you very much. Could you also show me how I can set the number format to "#,##0.00"
 
Upvote 0
Re: help with vba code to calculate column totals

Like
Code:
Sub kevinh2320()
   Dim Rng As Range
   For Each Rng In Range("I:I").SpecialCells(xlConstants).Areas
      With Rng.Offset(Rng.Count)(1)
         .Formula = "=sum(" & Rng.Address & ")"
         .NumberFormat = "#,##0.00"
      End With
   Next Rng
End Sub
 
Upvote 0

Forum statistics

Threads
1,224,817
Messages
6,181,147
Members
453,021
Latest member
Justyna P

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