VBA Browse Multiple Files and Copy Data

unknownymous

Board Regular
Joined
Sep 19, 2017
Messages
160
Hi Guys,

I have an open binary excel file (named "Masterfile"). I badly need the codes where the macro will browse from certain Source Folder and import multiple files onto the binary file. There are 3 files inside the Source folder namely: 1.) Survey.xlsx 2.) Checklist.xlsx 3.) CB.csv . I need to copy all 3 files and all the tabs inside it.


Any help will be much appreciated.
 

Yongle

Well-known Member
Joined
Mar 11, 2015
Messages
4,678
Office Version
365
Platform
Windows
Put VBA in standard module in Masterfile
Amend source folder
Code:
Sub ImportFiles()
    Const fpath = "[COLOR=#ff0000]C:\Folder\Source[/COLOR]"
    Dim f, sh, wb, wbMe As Workbook
    Set wbMe = ThisWorkbook
    Application.ScreenUpdating = False
    
    For Each f In Array("Survey.xlsx", "Checklist.xlsx", "CB.csv")
        Set wb = Workbooks.Open(fpath & "\" & f)
            For Each sh In wb.Sheets
                sh.Copy after:=wbMe.Sheets(wbMe.Sheets.Count)
            Next sh
        wb.Close False
    Next f
End Sub
 

unknownymous

Board Regular
Joined
Sep 19, 2017
Messages
160
Cool! By the way, can we use GetOpenFilePath instead of the direct path directory as the Source folder directory may change. Lastly, what if I want to import everything in the Source folder not just what I stated initially (as some files might be added but normally in xlsx, xls & csv format)?

Any help will be much appreciated.
 

Yongle

Well-known Member
Joined
Mar 11, 2015
Messages
4,678
Office Version
365
Platform
Windows
Try..

Code:
[COLOR=#2f4f4f]Sub ImportFiles[/COLOR]()
    Dim f, fpath As String
    fpath = GetFolder & "\"
    Application.ScreenUpdating = False
    f = Dir(fpath)
    Do While Len(f) > 0
        Select Case Right(f, Len(f) - InStrRev(f, "."))
            Case "xls", "xlsx", "csv"
                OpenFile (fpath & f)
        End Select
        f = Dir
    Loop
End Sub

[COLOR=#2f4f4f]Function GetFolder[/COLOR]() As String
    Dim f As String
    With Application.FileDialog(msoFileDialogFolderPicker)
        .Title = "Select a Folder"
        .AllowMultiSelect = False
        .InitialFileName = ThisWorkbook.Path
        If .Show <> -1 Then GoTo There
        f = .SelectedItems(1)
    End With
There:
    GetFolder = f
End Function

[COLOR=#2f4f4f]Private Sub OpenFile[/COLOR](filepath)
    Dim sh, wb As Workbook, wbMe As Workbook
    Set wbMe = ThisWorkbook
    Set wb = Workbooks.Open(filepath)
        For Each sh In wb.Sheets
            sh.Copy after:=wbMe.Sheets(wbMe.Sheets.Count)
        Next sh
    wb.Close False
End Sub
 

unknownymous

Board Regular
Joined
Sep 19, 2017
Messages
160
It worked! I have just one problem as I put the codes on an add-in macro file so the files we're attached on this file instead of the active workbook. How can attached those files on the active workbook? By the way, the name of the workbook has a word "Master" (like Math Master, English Master, etc) on the file name and usually in .xlsb & .xlxs format. Thanks a lot for the help.
 

Forum statistics

Threads
1,082,272
Messages
5,364,155
Members
400,784
Latest member
reddsables

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top