VBA to copy certain columns from multiple workbooks with multiple worksheet based on criteria into master workbook

nathanmav

Board Regular
Joined
Dec 11, 2012
Messages
123
Office Version
  1. 2019
  2. 2016
Platform
  1. Windows
Hi everyone,

I would like to ask for help about the code I found and I tried to modify it but I'm not lucky to make it work.
I have a total of eight (8) workbooks with more than one (1) worksheets. What I'm trying to achieved is copy a certain column if the condition is met.

Here is the code:
VBA Code:
Sub copydata()
   
    Dim lastrow As Integer
    Dim i As Integer As Integer
    Dim erow As Integer
    Dim xlsDestination As Workbook  'Master Workbook
    Dim xlsSource As Workbook       'Source Workbook
    Dim xlsDestSheet As Worksheet   'Destination Sheet
    Dim xlsSourceSheet As Worksheet 'Source Sheet
    Dim RefNo, Rev, Desc, DateSub

    Application.ScreenUpdating = False
       
    Set xlsDestination = ThisWorkbook
    Set xlsDestSheet = xlsDestination.Sheets("Master")
   
    Set xlsSource = Workbooks.Open("C:\Users\User\Desktop\Report\Source1.xlsx") 'I have lots of source workbooks
    Set xlsSourceSheet = xlsSource.Sheets("Sheet1") 'The problem here is source file composed of more than 1 sheet in every workbooks
   
    lastrow = xlsDestSheet.Range("A" & Rows.Count).End(xlUp).Row

    For i = 12 To lastrow 'starting row to copy in Source File
        If xlsSourceSheet.Cells(i, 13).Value = "C" And xlsSourceSheet.Cells(i, 17).Value = "LT" Then ' This the condition if condition is met
            'change the column numbers to the relevant number (from Source Workbook)
            RefNo = xlsSourceSheet.Cells(i, 2).Value
            Rev = xlsSourceSheet.Cells(i, 3).Value
            Desc = xlsSourceSheet.Cells(i, 5).Value
            DateSub = xlsSourceSheet.Cells(i, 10).Value

            erow = xlsDestSheet.Cells(xlsDestSheet.Rows.Count, 1).End(xlUp).Offset(1, 0).Row

            'change the column numbers to the relevant number (to Master Workbook)
            xlsDestSheet.Cells(erow, 4).Value = RefNo
            xlsDestSheet.Cells(erow, 5).Value = Rev
            xlsDestSheet.Cells(erow, 6).Value = Desc
            xlsDestSheet.Cells(erow, 7).Value = DateSub
        End If
    Next i
Application.ScreenUpdating = True

End Sub

Thank you in advance!
 
My pleasure. :)

Use this approach for all "Copy" lines where you do not want to copy the hyperlinks:
VBA Code:
Intersect(.Range("B13:R" & lRow3).SpecialCells(xlCellTypeVisible), Union(.Columns(no.Column), .Columns(rev.Column), .Columns(desc.Column), .Columns(SD.Column)).EntireColumn).Copy
 odWS.Range("D" & lRow1).PasteSpecial xlPasteValues
 
Upvote 0

Excel Facts

Excel Joke
Why can't spreadsheets drive cars? They crash too often!
My pleasure. :)

Use this approach for all "Copy" lines where you do not want to copy the hyperlinks:
VBA Code:
Intersect(.Range("B13:R" & lRow3).SpecialCells(xlCellTypeVisible), Union(.Columns(no.Column), .Columns(rev.Column), .Columns(desc.Column), .Columns(SD.Column)).EntireColumn).Copy
odWS.Range("D" & lRow1).PasteSpecial xlPasteValues

Mumps,

There is an error showing compile error.

1597087596385.png


Thank you
 
Upvote 0
Try:
VBA Code:
Sub COPYDATA()
    Application.ScreenUpdating = False
    Dim lRow1 As Long, lRow2 As Long, lRow3 As Long
    Dim odWS As Worksheet, faWS As Worksheet, srcWB As Workbook, ws As Worksheet, od As Range, fa As Range
    Dim no As Range, desc As Range, rev As Range, SD As Range, RD As Range, Stat As Range, shArr As Variant, i As Long
    Set odWS = ThisWorkbook.Sheets("OVERDUE")
    Set faWS = ThisWorkbook.Sheets("FOR ACTION")
    Const strPath As String = "D:\Sample3\" 'change the folder path to suit your needs
    ChDir strPath
    strExtension = Dir(strPath & "*.xlsx")
    Do While strExtension <> ""
        If strExtension = "1. Material.xlsx" Then
            Set srcWB = Workbooks.Open(strPath & strExtension)
            shArr = Array("CV", "ST", "AR", "EL", "ME")
            With srcWB
                For i = LBound(shArr) To UBound(shArr)
                    Set ws = Sheets(shArr(i))
                    If ws.AutoFilterMode Then ws.AutoFilterMode = False
                    lRow1 = odWS.Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row + 1
                    lRow2 = faWS.Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row + 1
                    With ws
                        lRow3 = .Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row + 1
                        Set od = .rows(12).Find("OVERDUE")
                        Set fa = .rows(12).Find("FOR ACTION")
                        With .rows(12)
                            Set no = .Find("Ref No")
                            Set desc = .Find("Desc")
                            Set rev = .Find("Rev")
                            Set SD = .Find("Sub Date")
                            Set RD = .Find("Rep Date")
                            Set Stat = .Find("Stat")
                        End With
                        .Range("A12").AutoFilter od.Column, Criteria1:="OVERDUE"
                        Intersect(.Range("B13:R" & lRow3).SpecialCells(xlCellTypeVisible), Union(.Columns(no.Column), .Columns(rev.Column), .Columns(desc.Column), .Columns(SD.Column)).EntireColumn).Copy
                        odWS.Range("D" & lRow1).PasteSpecial xlPasteValues
                        .Range("A12").AutoFilter
                        .Range("A12").AutoFilter fa.Column, Criteria1:="FOR ACTION"
                        Intersect(.Range("B13:R" & lRow3).SpecialCells(xlCellTypeVisible), Union(.Columns(no.Column), .Columns(rev.Column), .Columns(desc.Column), .Columns(SD.Column), .Columns(RD.Column), .Columns(Stat.Column)).EntireColumn).Copy
                        faWS.Range("D" & lRow2).PasteSpecial xlPasteValues
                        .Range("A12").AutoFilter
                    End With
                Next i
                .Close savechanges:=False
            End With
        End If
        strExtension = Dir
    Loop
    Application.ScreenUpdating = True
End Sub
You still have some formulas in the OVERDUE and FOR ACTION sheets. Delete the formulas before you run the macro.
 
Upvote 0
Try:
VBA Code:
Sub COPYDATA()
    Application.ScreenUpdating = False
    Dim lRow1 As Long, lRow2 As Long, lRow3 As Long
    Dim odWS As Worksheet, faWS As Worksheet, srcWB As Workbook, ws As Worksheet, od As Range, fa As Range
    Dim no As Range, desc As Range, rev As Range, SD As Range, RD As Range, Stat As Range, shArr As Variant, i As Long
    Set odWS = ThisWorkbook.Sheets("OVERDUE")
    Set faWS = ThisWorkbook.Sheets("FOR ACTION")
    Const strPath As String = "D:\Sample3\" 'change the folder path to suit your needs
    ChDir strPath
    strExtension = Dir(strPath & "*.xlsx")
    Do While strExtension <> ""
        If strExtension = "1. Material.xlsx" Then
            Set srcWB = Workbooks.Open(strPath & strExtension)
            shArr = Array("CV", "ST", "AR", "EL", "ME")
            With srcWB
                For i = LBound(shArr) To UBound(shArr)
                    Set ws = Sheets(shArr(i))
                    If ws.AutoFilterMode Then ws.AutoFilterMode = False
                    lRow1 = odWS.Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row + 1
                    lRow2 = faWS.Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row + 1
                    With ws
                        lRow3 = .Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row + 1
                        Set od = .rows(12).Find("OVERDUE")
                        Set fa = .rows(12).Find("FOR ACTION")
                        With .rows(12)
                            Set no = .Find("Ref No")
                            Set desc = .Find("Desc")
                            Set rev = .Find("Rev")
                            Set SD = .Find("Sub Date")
                            Set RD = .Find("Rep Date")
                            Set Stat = .Find("Stat")
                        End With
                        .Range("A12").AutoFilter od.Column, Criteria1:="OVERDUE"
                        Intersect(.Range("B13:R" & lRow3).SpecialCells(xlCellTypeVisible), Union(.Columns(no.Column), .Columns(rev.Column), .Columns(desc.Column), .Columns(SD.Column)).EntireColumn).Copy
                        odWS.Range("D" & lRow1).PasteSpecial xlPasteValues
                        .Range("A12").AutoFilter
                        .Range("A12").AutoFilter fa.Column, Criteria1:="FOR ACTION"
                        Intersect(.Range("B13:R" & lRow3).SpecialCells(xlCellTypeVisible), Union(.Columns(no.Column), .Columns(rev.Column), .Columns(desc.Column), .Columns(SD.Column), .Columns(RD.Column), .Columns(Stat.Column)).EntireColumn).Copy
                        faWS.Range("D" & lRow2).PasteSpecial xlPasteValues
                        .Range("A12").AutoFilter
                    End With
                Next i
                .Close savechanges:=False
            End With
        End If
        strExtension = Dir
    Loop
    Application.ScreenUpdating = True
End Sub
You still have some formulas in the OVERDUE and FOR ACTION sheets. Delete the formulas before you run the macro.

Nice mumps it works. Thank you very much for your help. :)
 
Upvote 0
Hi mumps,

I have a question regarding this thread the code you give me is working and it helps me a lot. But I just notice that there is no condition when filtering returns no data I mean for example the code will filter overdue but no rows with overdue status the problem is that this code will copy it even if its blank. Is there a way that it will skip if no data found.

Thank you
 
Upvote 0
Try:
VBA Code:
Sub COPYDATA()
    Application.ScreenUpdating = False
    Dim lRow1 As Long, lRow2 As Long, lRow3 As Long
    Dim odWS As Worksheet, faWS As Worksheet, srcWB As Workbook, ws As Worksheet, od As Range, fa As Range
    Dim no As Range, desc As Range, rev As Range, SD As Range, RD As Range, Stat As Range, shArr As Variant, i As Long
    Set odWS = ThisWorkbook.Sheets("OVERDUE")
    Set faWS = ThisWorkbook.Sheets("FOR ACTION")
    Const strPath As String = "D:\Sample3\" 'change the folder path to suit your needs
    ChDir strPath
    strExtension = Dir(strPath & "*.xlsx")
    Do While strExtension <> ""
        If strExtension = "1. Material.xlsx" Then
            Set srcWB = Workbooks.Open(strPath & strExtension)
            shArr = Array("CV", "ST", "AR", "EL", "ME")
            With srcWB
                For i = LBound(shArr) To UBound(shArr)
                    Set ws = Sheets(shArr(i))
                    If ws.AutoFilterMode Then ws.AutoFilterMode = False
                    lRow1 = odWS.Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row + 1
                    lRow2 = faWS.Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row + 1
                    With ws
                        lRow3 = .Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row + 1
                        Set od = .rows(12).Find("OVERDUE")
                        Set fa = .rows(12).Find("FOR ACTION")
                        With .rows(12)
                            Set no = .Find("Ref No")
                            Set desc = .Find("Desc")
                            Set rev = .Find("Rev")
                            Set SD = .Find("Sub Date")
                            Set RD = .Find("Rep Date")
                            Set Stat = .Find("Stat")
                        End With
                        If WorksheetFunction.CountIf(.Range(.Cells(13, od.Column), .Cells(lRow1 - 1, od.Column)), "OVERDUE") > 0 Then
                            .Range("A12").AutoFilter od.Column, Criteria1:="OVERDUE"
                            Intersect(.Range("B13:R" & lRow3).SpecialCells(xlCellTypeVisible), Union(.Columns(no.Column), .Columns(rev.Column), .Columns(desc.Column), .Columns(SD.Column)).EntireColumn).Copy
                            odWS.Range("D" & lRow1).PasteSpecial xlPasteValues
                            .Range("A12").AutoFilter
                        End If
                        If WorksheetFunction.CountIf(.Range(.Cells(13, fa.Column), .Cells(lRow2 - 1, fa.Column)), "FOR ACTION") > 0 Then
                            .Range("A12").AutoFilter fa.Column, Criteria1:="FOR ACTION"
                            Intersect(.Range("B13:R" & lRow3).SpecialCells(xlCellTypeVisible), Union(.Columns(no.Column), .Columns(rev.Column), .Columns(desc.Column), .Columns(SD.Column), .Columns(RD.Column), .Columns(Stat.Column)).EntireColumn).Copy
                            faWS.Range("D" & lRow2).PasteSpecial xlPasteValues
                            .Range("A12").AutoFilter
                        End If
                    End With
                Next i
                .Close savechanges:=False
            End With
        End If
        strExtension = Dir
    Loop
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Hi mumps,

Thank you very much for your fast response.

I tried the formula but there are some problem if the first sheet has no rows with overdue the code will skip all the sheets even if there are some sheets with overdue status
but if its in the second or third sheet that has no rows overdue the code is working fine.

Thank you again
 
Upvote 0

Forum statistics

Threads
1,214,829
Messages
6,121,827
Members
449,051
Latest member
excelquestion515

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