VBA SUMIFS if the adjacent cell is not blank

Allan91

New Member
Joined
Dec 17, 2020
Messages
33
Office Version
  1. 2019
Platform
  1. Windows
Hey Guys,

I have created this book which draws a bunch of raw data onto a sheet ("Raw Data") which is later transferred to another sheet ("Clean Data") with a copy and remove duplicates using VBA.

I need a VBA code which will SUMIFS the relevant data from Raw Data sheet on to Clean Data Sheet Column E, until the last row on column D is blank. I am intending to use this for my dynamic charts so I just can't write the regular formula and drag down. Please see the images uploaded to see what I mean.

I want the SUMIFS to work with the item name and name of the month, extending to the right with the 12 months.

It would be great if you guys could lend me a hand at this as I am a complete newbie and my VBA knowledge does not go beyond copying and removing duplicates.
 

Attachments

  • Raw Data.PNG
    Raw Data.PNG
    30.2 KB · Views: 9
  • Clean Data.PNG
    Clean Data.PNG
    10 KB · Views: 9

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
If your Month name is in E1 at sheet ("Clean Data") and your source data is in C3:E50 at sheet ("Raw Data") Then:
Input this at E4 (for D4) and Press CTRL+SHIFT+ENTER
Excel Formula:
=INDEX('Raw Data'!$C$3:$E$50,MATCH(1,($E$1='Raw Data'!$C$3:$C$50)*(D4='Raw Data'!$D$3:$D$50),0),3)
 
Upvote 0
Hi maabadi,

I have already tried INDEX MATCH but I am going to use this with dynamic charts. I don't know how many items will be there in the end of the each month. So if I have INDEX MATCH formulas copied in the cells the charts get confused and all broken. This is why I was thinking if I could use a VBA code so that it will sumif only if there is data on the adjacent cell.
 
Upvote 0
If your Month name is in E1 at sheet ("Clean Data") and your source data is in C3:E50 at sheet ("Raw Data") Then:
Input this at E4 (for D4) and Press CTRL+SHIFT+ENTER
Excel Formula:
=INDEX('Raw Data'!$C$3:$E$50,MATCH(1,($E$1='Raw Data'!$C$3:$C$50)*(D4='Raw Data'!$D$3:$D$50),0),3)

Hi maabadi,

I have already tried INDEX MATCH but I am going to use this with dynamic charts. I don't know how many items will be there in the end of the each month. So if I have INDEX MATCH formulas copied in the cells the charts get confused and all broken. This is why I was thinking if I could use a VBA code so that it will sumif only if there is data on the adjacent cell.
 
Upvote 0
Sorry @Allan91
For delaying at reply.
For this VBA I suppose the Cell E1 Value at each sheet equals Month Name
If you want this Based on Worksheet name that they name are month names
Change ws.Range("E1").Value to ws.Name
Check this:
VBA Code:
Sub CleanData()
Dim ws As Worksheet
Dim Lr As Long, i As Long, j As Long
Dim MyRange As Range, Cell As Range

Lr = Sheets("sheet1").Cells(Rows.Count, 3).End(xlUp).Row
For i = 4 To Lr
Sheets("sheet1").Range("B" & i).Value = Application.WorksheetFunction.Concat(Sheets("sheet1").Range("C" & i).Value, Sheets("sheet1").Range("D" & i).Value)
Next i

For Each ws In Worksheets
If ws.Name <> "Sheet1" Then
Set MyRange = ws.Range("E4:E11")
For Each Cell In MyRange
On Error Resume Next
Cell.Value = Application.WorksheetFunction.VLookup(ws.Range("E1").Value & Cell.Offset(0, -1).Value, Sheets("sheet1").Range("B4:E" & Lr), 4, False)
Next Cell
End If
Next ws
Sheets("sheet1").Range("B3").EntireColumn.ClearContents
End Sub
 
Upvote 0
if you have repeated criteria and want Sumifs Use this:
For this also
If you want this Based on Worksheet name that they name are month names
Change ws.Range("E1").Value to ws.Name
AND for Both Change Sheet1 to Your Raw Data sheet name.
VBA Code:
Sub CleanData()
Dim ws As Worksheet
Dim Lr As Long, i As Long, j As Long
Dim MyRange As Range, Cell As Range

Lr = Sheets("sheet1").Cells(Rows.Count, 3).End(xlUp).Row

For Each ws In Worksheets
If ws.Name <> "Sheet1" Then
Set MyRange = ws.Range("E4:E11")
For Each Cell In MyRange
On Error Resume Next
Cell.Value = Application.WorksheetFunction.SumIfs(Sheets("Sheet1").Range("E4:E" & Lr), Sheets("Sheet1").Range("C4:C" & Lr), ws.Range("E1").Value, Sheets("Sheet1").Range("D4:D" & Lr), ws.Range("D" & Cell.Row).Value)
Next Cell
End If
Next ws
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,520
Messages
6,120,003
Members
448,935
Latest member
ijat

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