I need a vba code to sum category 1 and sum category 2 separately and then add a line to the end of the row to sum both the totals.

PriyaV

New Member
Joined
Jul 1, 2021
Messages
5
Office Version
  1. 365
Platform
  1. Windows
I need a vba code to sum category 1 and sum category 2 separately and then add a line to the end of the row to sum both the totals. In all the cases, the number of rows and columns vary.
So there shouldn't be any coding specifying range. It can activesheet and activecell.

here are the two queries i have
1. I wrote a coding for the category 1, but it takes up ranges and also I have set active cell, so that it can tell where to write the sum formula.
2. I have done this for both the category, but when I make the total (category), adding the two activecells, don't turn up as formula.

Sub Find_Text_Sum_up_FillRight()

last = Cells(Rows.Count, "A").End(xlUp).Row
For i = last To 1 Step -1
If (Cells(i, "A").Value) Like "Sum (Category1)" Then
Cells(i, "C").Cells.Select
ActiveCell.FormulaR1C1 = "=SUM(R[-13]C:R[-1]C)"
Selection.Copy
Range(Selection, Selection.End(xlToRight)).Select
ActiveSheet.Paste
End If
Next i
Set myActiveCell1 = ActiveCell
End Sub





1625152466133.png
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
Hi and welcome to MrExcel:

You could confirm if the following values are constant:
Category 1
Sum (Category 1)
Category 2
Sum (Category 2)
And row 4 always has all the headings that are going to exist in the columns.

If the above is correct, try this:

VBA Code:
Sub SumCategory()
  Dim i As Long, lc As Long
  Dim f As Range
  Dim ini As Long, fin As Long, fin1 As Long
  
  lc = Cells(4, Columns.Count).End(1).Column
  For i = 1 To 2
    Set f = Range("A:A").Find("Category " & i, , xlValues, xlWhole, , , False)
    If Not f Is Nothing Then
      ini = f.Row + 1
      Set f = Range("A:A").Find("Sum (Category " & i & ")", , xlValues, xlWhole, , , False)
      If Not f Is Nothing Then
        fin = f.Row
        If i = 1 Then fin1 = fin
        If ini <= fin Then
          With Range(Cells(fin, "C"), Cells(fin, lc))
            .Formula = "=SUM(C" & ini & ":C" & fin - 1 & ")"
            .Value = .Value
          End With
          If i = 2 Then
            With Range(Cells(fin + 1, "C"), Cells(fin + 1, lc))
              .Formula = "=SUM(C" & fin1 & ",C" & fin & ")"
              .Value = .Value
            End With
          End If
        End If
      End If
    End If
  Next
End Sub
 
Last edited:
Upvote 0
Hi and welcome to MrExcel:

You could confirm if the following values are constant:
Category 1
Sum (Category 1)
Category 2
Sum (Category 2)
And row 4 always has all the headings that are going to exist in the columns.

If the above is correct, try this:

VBA Code:
Sub SumCategory()
  Dim i As Long, lc As Long
  Dim f As Range
  Dim ini As Long, fin As Long, fin1 As Long
 
  lc = Cells(4, Columns.Count).End(1).Column
  For i = 1 To 2
    Set f = Range("A:A").Find("Category " & i, , xlValues, xlWhole, , , False)
    If Not f Is Nothing Then
      ini = f.Row + 1
      Set f = Range("A:A").Find("Sum (Category " & i & ")", , xlValues, xlWhole, , , False)
      If Not f Is Nothing Then
        fin = f.Row
        If i = 1 Then fin1 = fin
        If ini <= fin Then
          With Range(Cells(fin, "C"), Cells(fin, lc))
            .Formula = "=SUM(C" & ini & ":C" & fin - 1 & ")"
            .Value = .Value
          End With
          If i = 2 Then
            With Range(Cells(fin + 1, "C"), Cells(fin + 1, lc))
              .Formula = "=SUM(C" & fin1 & ",C" & fin & ")"
              .Value = .Value
            End With
          End If
        End If
      End If
    End If
  Next
End Sub
Hi,

Greetings!
Thanks for the quick help.
Unfortunately the code doesn't enter the loop for summation.
Actually the headings category 1 and 2 is not constant. I just gave them for an example. It can be any name.
Is it possible you can still help me on this?

Thanks....
 
Upvote 0
In which row does the data begin to be added?
In which row are the headings?
are the words sum, sum, and total constant?
 
Upvote 0
In which row does the data begin to be added?
In which row are the headings?
are the words sum, sum, and total constant?
Hi,

The data and headers would be the same as given in the example table.
Except that the names wouldn't be as category 1 and 2, it would be something like - chemicals, nonchemicals.
Yes, the words sum, sum and total are constant.
 
Upvote 0
The data and headers would be the same as given in the example table.
You could be more specific, in your image we don't see the row number. So I ask in which row the headings are and in which row the data begins.

Yes, the words sum, sum and total are constant.
That is good news, I just wait for an answer to my previous questions.
 
Upvote 0
You could be more specific, in your image we don't see the row number. So I ask in which row the headings are and in which row the data begins.


That is good news, I just wait for an answer to my previous questions.
so sorry about that. I am attaching one more pic, with the cell range.
The formulas are just a representation for what needs to be added...


1625519221928.png


Am so thankful to you for helping me out in this.
 
Upvote 0
In which row does the data begin to be added? 4
In which row are the headings? 5
are the words sum, sum, and total constant? Yes

According with the last.

VBA Code:
Sub SumCategory()
  Dim i As Long, lc As Long
  Dim f As Range
  Dim ini As Long, fin1 As Long, fin2 As Long
  
  lc = Cells(4, Columns.Count).End(1).Column
  ini = 6
  Set f = Range("A:A").Find("Sum", , xlValues, xlPart, , , False)
  If Not f Is Nothing Then
    fin1 = f.Row
    With Range(Cells(fin1, "C"), Cells(fin1, lc))
      .Formula = "=SUM(C" & ini & ":C" & fin1 - 1 & ")"
      .Value = .Value
    End With
  End If
  
  ini = fin1 + 2
  Set f = Range("A:A").Find("Sum", , xlValues, xlPart, , xlPrevious, False)
  If Not f Is Nothing Then
    fin2 = f.Row
    With Range(Cells(fin2, "C"), Cells(fin2, lc))
      .Formula = "=SUM(C" & ini & ":C" & fin2 - 1 & ")"
      .Value = .Value
    End With
  End If
  
  With Range(Cells(fin2 + 1, "C"), Cells(fin2 + 1, lc))
    .Formula = "=SUM(C" & fin1 & ",C" & fin2 & ")"
    .Value = .Value
  End With
End Sub
 
Upvote 0
Hi,

@DanteAmor , Sorry for the delayed response, but that works perfectly fine.
The one things, I had to do is that the Sum row is merged and that your code works, if its unmerged.., but otherwise, this is a perfect code. Thanks again
 
Upvote 0

Forum statistics

Threads
1,214,899
Messages
6,122,155
Members
449,068
Latest member
shiz11713

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