SUM cells with a specific column header from multiple worksheets - Using VBA

Status
Not open for further replies.

isanka88

New Member
Joined
Dec 12, 2020
Messages
13
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
Hi All Good people

I'm new to VBA and I'm seeking some assistance with a macro. I have a workbook with multiple sheets. First worksheet is call master worksheet. In the master worksheet I have sheet names. I would like to sum all cells below a specific column header named, "My text." across all my worksheets and insert the sum values in master sheet. For an example lets suppose I have 4 worksheets as Master, Shee1, Sheet2 and Sheet3. In the Master sheet I have each sheet names from A1 to C1. So I want the sum value below each of these sheet names. The sum value should pull from sheet 1, 2 & 3 based on heading name "My Text" But the column is dynamic in position (doesn't always fall under the same column or row)

Is there a way to find the term "My text" and sum all cells that fall under that column header?

Please let me know if I can provide any additional details to help with my request. I have attached my original workbook as below with my requirement explained on it

https://drive.google.com/file/…wDb1_C5Llb7eGOoDD1TH/view

Thanks in advance for your help!
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
Hi. Try this code.
VBA Code:
Sub GetSums()
 Dim lngCol As Long, wsName As Range
  With Sheets("Master")
   If .[C3] <> "" Then .Range("C3", .[B3].End(2)) = ""
   For Each wsName In .Range("C2", .[B2].End(2))
    lngCol = Sheets(wsName.Value).Rows(1).Find("My Text").Column
     wsName.Offset(1).Value = _
      Evaluate("Sum('" & wsName.Value & "'!" & Cells(3, lngCol + 1).Address & ":" & _
       Sheets(wsName.Value).Cells(Rows.Count, lngCol + 1).End(3).Address & ")")
   Next wsName
  End With
End Sub
 
Upvote 0
Hi Osvaldo
I do not know what to say and how to thank you. this is awesomely worked for me. My happiness is out of verbal definitions. You guys are amazing. Because of valuable people like you, Life is very easy for beginners like us. Thank you soo much for this. I owe you a lot for this.:love::love::love::love::love::love::love:
 
Upvote 0
Hi, Isanka.
Thank you very much for your kind words and for your feedback.
We're glad to have contributed in some way to solve your demand. :)
Have a great weekend.
 
Upvote 0
Hi @Osvaldo Palmeiro

Here I have come again for seek your advise. You did a wonderful job last time. Now I need to add 1 more condition to the below macro you gave me.

Sub GetSums()
Dim lngCol As Long, wsName As Range
With Sheets("Master")
If .[C3] <> "" Then .Range("C3", .[B3].End(2)) = ""
For Each wsName In .Range("C2", .[B2].End(2))
lngCol = Sheets(wsName.Value).Rows(1).Find("My Text").Column
wsName.Offset(1).Value = _
Evaluate("Sum('" & wsName.Value & "'!" & Cells(3, lngCol + 1).Address & ":" & _
Sheets(wsName.Value).Cells(Rows.Count, lngCol + 1).End(3).Address & ")")
Next wsName
End With
End Sub

I want to add one more condition to the Sum. I think this can be done with SUM IF. In my worksheets I have department as "ABC in B column. I need to get the sum only for ABC department and put the value in "Master" sheet. I have attached my workbook in below google drive link.. Kindly have a look


1628391610458.png

1628391941224.png
 
Upvote 0
Status
Not open for further replies.

Forum statistics

Threads
1,223,893
Messages
6,175,240
Members
452,621
Latest member
Laura_PinksBTHFT

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