[VBA] [Data Consolidation][Speed up]

zeromax1

Board Regular
Joined
Mar 20, 2020
Messages
52
Office Version
  1. 365
Platform
  1. Windows
Hi Professional, I would like to ask the help for the VBA code speed up & improvement.

I have to consolidate the sub-workbooks to my master workbook. Each workbooks have the same tab name to contain the data.

Eg: I have to copy the data in column F from "Monday" Tab in sub workbooks to my master workbook in the column B of "Monday" Tab and subtract the number.
I have to copy the data in column C from "Monday" Tab in sub workbooks to my master workbook in the column F of "Monday" Tab.

1234567890.jpg
I found a VBA code to consolidate the data, but the speed seems too slow and the code is not perfect.

For the convenient, I skip to paste the similar code of "Tuesday","Wednesday", etc tab.

VBA Code:
Sub Consolidatfiles()

On Error Resume Next

    Application.ScreenUpdating = False

    Dim FileName As Variant, wkbSource As Workbook, wkbDest As Workbook
    Set wkbDest = ThisWorkbook
    
    FileName = Application.GetOpenFilename("Excel Files (*.xlsx*),*.xlsx*", , "Select Excel Files", , True)
    
    If Not IsArray(FileName) Then
        MsgBox "No File Selected"
        Exit Sub
    End If
    
    For i = LBound(FileName) To UBound(FileName)
        Set wkbSource = Workbooks.Open(FileName(i))
        With wkbSource
            .Worksheets("Monday").Range("C5:C" & Range("C" & Rows.Count).End(xlUp).Row).Copy _
            Destination:=wkbDest.Worksheets("Monday").range("F7").End(xlUp)

            .Worksheets("Monday").Range("F5:F" & Range("F" & Rows.Count).End(xlUp).Row-1).Copy _
            Destination:=wkbDest.Worksheets("Monday").range("F7").End(xlUp).PasteSpecial Paste:=xlPasteAll, Operation:=xlSubtract 

            wkbSource.Close savechanges = False
        End With
    Next i
    
    Application.CutCopyMode = False
    Application.ScreenUpdating = True
  
    
End Sub

Thank you very much.
 

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
Your macro has some errors and you cannot see them because you have this statement at the beginning of the code.
On Error Resume Next

I present you another approach, try and tell me.
in the array you can put the names of the sheets to consolidate.
VBA Code:
Sub Consolidatfiles()
  Dim wb1 As Workbook, sh1 As Worksheet
  Dim FileName As Variant, sheetName As Variant, arr As Variant
  Dim i As Long, j As Long
  Dim a() As Variant, b() As Variant
  
  Application.ScreenUpdating = False
  
  FileName = Application.GetOpenFilename("Excel Files (*.xlsx*),*.xlsx*", , "Select Excel Files", , True)
  
  If Not IsArray(FileName) Then
    MsgBox "No File Selected"
    Exit Sub
  End If
  
  arr = Array("Monday", "Tuesday", "Wednesday", "Thursday", "Friday")
  
  For i = LBound(FileName) To UBound(FileName)
    Set wb1 = Workbooks.Open(FileName(i))
    
    For Each sheetName In arr
      Set sh1 = wb1.Sheets(sheetName)
      Erase a, b
      a = sh1.Range("C5:F" & sh1.Range("C" & Rows.Count).End(3).Row).Value
      ReDim b(1 To UBound(a, 1))
      
      For j = 1 To UBound(a, 1)
        b(j) = a(j, 1) - a(j, 4)
      Next j
      
      ThisWorkbook.Sheets(sheetName).Range("F" & Rows.Count).End(3)(2).Resize(UBound(b)).Value = Application.Transpose(b())
    Next sheetName
    
    wb1.Close False
  Next i
  
  Application.ScreenUpdating = True
End Sub
 
Upvote 0
Hi DanteAmor

Thank you for your help, but I found there is an error when I run your code.

1599096405529.png


1599096435175.png

Your macro has some errors and you cannot see them because you have this statement at the beginning of the code.
On Error Resume Next

I present you another approach, try and tell me.
in the array you can put the names of the sheets to consolidate.
VBA Code:
Sub Consolidatfiles()
  Dim wb1 As Workbook, sh1 As Worksheet
  Dim FileName As Variant, sheetName As Variant, arr As Variant
  Dim i As Long, j As Long
  Dim a() As Variant, b() As Variant
 
  Application.ScreenUpdating = False
 
  FileName = Application.GetOpenFilename("Excel Files (*.xlsx*),*.xlsx*", , "Select Excel Files", , True)
 
  If Not IsArray(FileName) Then
    MsgBox "No File Selected"
    Exit Sub
  End If
 
  arr = Array("Monday", "Tuesday", "Wednesday", "Thursday", "Friday")
 
  For i = LBound(FileName) To UBound(FileName)
    Set wb1 = Workbooks.Open(FileName(i))
   
    For Each sheetName In arr
      Set sh1 = wb1.Sheets(sheetName)
      Erase a, b
      a = sh1.Range("C5:F" & sh1.Range("C" & Rows.Count).End(3).Row).Value
      ReDim b(1 To UBound(a, 1))
     
      For j = 1 To UBound(a, 1)
        b(j) = a(j, 1) - a(j, 4)
      Next j
     
      ThisWorkbook.Sheets(sheetName).Range("F" & Rows.Count).End(3)(2).Resize(UBound(b)).Value = Application.Transpose(b())
    Next sheetName
   
    wb1.Close False
  Next i
 
  Application.ScreenUpdating = True
End Sub
 
Upvote 0
I found there is an error when I run your code
That error is because in column C or in column F you have texts instead of numbers. Then it cannot perform the subtraction operation.
Review your data and correct it.
If you want to know where exactly you have the error. When the error occurs press the Debug button.
Mouse over the variables FileName (file name), sheetName (sheet name) and j (row number).
Take note of those data. Open file, check sheet and row. Correct data and try again.
 
Upvote 0
Oh DanteAmor

Thank you for your quick response. But column C in the raw data is the text (eg:Name) not the number.

Please see the below picture, I have to copy the data in red color from left workbook (raw data) to the right (master workbook). They have the exact name from Monday to Friday.

Only the value have to substract

1599100070550.png


That error is because in column C or in column F you have texts instead of numbers. Then it cannot perform the subtraction operation.
Review your data and correct it.
If you want to know where exactly you have the error. When the error occurs press the Debug button.
Mouse over the variables FileName (file name), sheetName (sheet name) and j (row number).
Take note of those data. Open file, check sheet and row. Correct data and try again.
 

Attachments

  • 1599099993754.png
    1599099993754.png
    73 KB · Views: 3
Upvote 0
your original macro copies the values of column C and then subtracts the value of column F from those values. but let's forget your macro and my macro. Explain with examples what the end goal is. use the xl2bb tool to paste data ranges here (see my signature)
 
Upvote 0
Thank you DanteAmor, let me explain more about my idea.

I have many source workbooks that need to copy the specific data into my Master workbooks. For the source workbook, I have to copy the data from cell C5 to the last row in Column C to cell F7 in my master workbook.

Then I have to copy the number from cell F5 to the last row (exclude the grand total number) to Cell B7 and subtract it at the same time.

Each source workbook & master workbook has the same Tab name from "Monday to Sunday". All data need to copy from source workbook to master workbook in a same tab name. (Monday to Monday, Tuesday to Tuesday)

Please see my cap screen:
Left: source workbook
Right: master workbook
1599181709073.png


your original macro copies the values of column C and then subtracts the value of column F from those values. but let's forget your macro and my macro. Explain with examples what the end goal is. use the xl2bb tool to paste data ranges here (see my signature)
 
Upvote 0
Try this:

VBA Code:
Sub Consolidatfiles()
  Dim wb1 As Workbook, sh1 As Worksheet
  Dim FileName As Variant, sheetName As Variant, arr As Variant
  Dim i As Long, j As Long, lr1 As Long, lr2 As Long
  Dim a() As Variant, b() As Variant
  
  Application.ScreenUpdating = False
  
  FileName = Application.GetOpenFilename("Excel Files (*.xlsx*),*.xlsx*", , "Select Excel Files", , True)
  
  If Not IsArray(FileName) Then
    MsgBox "No File Selected"
    Exit Sub
  End If
  
  arr = Array("Monday", "Tuesday", "Wednesday", "Thursday", "Friday", "Saturday", "Sunday")
  
  For i = LBound(FileName) To UBound(FileName)
    Set wb1 = Workbooks.Open(FileName(i))
    
    For Each sheetName In arr
      Set sh1 = wb1.Sheets(sheetName)
      Erase a
      lr1 = sh1.Range("C" & Rows.Count).End(3).Row
      a = sh1.Range("F5:F" & lr1).Value
      
      For j = 1 To UBound(a, 1)
        a(j, 1) = -a(j, 1)
      Next j
      
      With ThisWorkbook.Sheets(sheetName)
        lr2 = .Range("B" & Rows.Count).End(3).Row + 1
        .Range("B" & lr2).Resize(UBound(a)).Value = a
        .Range("F" & lr2).Resize(UBound(a)).Value = sh1.Range("C5").Resize(UBound(a)).Value
      End With
    Next sheetName
    wb1.Close False
  Next i
  
  Application.ScreenUpdating = True
End Sub
 
Upvote 0
Thank you , DanteAmor.

It makes my life more eaiser.



Try this:

VBA Code:
Sub Consolidatfiles()
  Dim wb1 As Workbook, sh1 As Worksheet
  Dim FileName As Variant, sheetName As Variant, arr As Variant
  Dim i As Long, j As Long, lr1 As Long, lr2 As Long
  Dim a() As Variant, b() As Variant
 
  Application.ScreenUpdating = False
 
  FileName = Application.GetOpenFilename("Excel Files (*.xlsx*),*.xlsx*", , "Select Excel Files", , True)
 
  If Not IsArray(FileName) Then
    MsgBox "No File Selected"
    Exit Sub
  End If
 
  arr = Array("Monday", "Tuesday", "Wednesday", "Thursday", "Friday", "Saturday", "Sunday")
 
  For i = LBound(FileName) To UBound(FileName)
    Set wb1 = Workbooks.Open(FileName(i))
   
    For Each sheetName In arr
      Set sh1 = wb1.Sheets(sheetName)
      Erase a
      lr1 = sh1.Range("C" & Rows.Count).End(3).Row
      a = sh1.Range("F5:F" & lr1).Value
     
      For j = 1 To UBound(a, 1)
        a(j, 1) = -a(j, 1)
      Next j
     
      With ThisWorkbook.Sheets(sheetName)
        lr2 = .Range("B" & Rows.Count).End(3).Row + 1
        .Range("B" & lr2).Resize(UBound(a)).Value = a
        .Range("F" & lr2).Resize(UBound(a)).Value = sh1.Range("C5").Resize(UBound(a)).Value
      End With
    Next sheetName
    wb1.Close False
  Next i
 
  Application.ScreenUpdating = True
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,641
Messages
6,120,695
Members
448,979
Latest member
DET4492

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