• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member
  • Login

Macro to copy specific workbooks from sub-folders|VBA & Macros|Excel Forum|My Online Training Hub

You are here: Home / Macro to copy specific workbooks from sub-folders|VBA & Macros|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumVBA & MacrosMacro to copy specific workbooks fr…
sp_PrintTopic sp_TopicIcon
Macro to copy specific workbooks from sub-folders
Avatar
Howard Cohen
Member
Members
Level 0
Forum Posts: 56
Member Since:
December 8, 2016
sp_UserOfflineSmall Offline
1
August 20, 2020 - 3:23 am
sp_Permalink sp_Print sp_EditHistory

I have several files in sub folders on a network "\\account\man\

The sub folders are for eg "\\account\man\BR1\

"\\account\admin\BR2\

"\\account\admin\sammy\

Etc

I would like all files that contain "Template 2020.xlsm to be copied from the sub-folders for eg BR Sales Report template 2020.xlsm to C:\Sales Reports\

It would be appreciated if someone could amend my code

Sub CopyWorkbookstoanotherFolder()

'Declare Variables
Dim FSO
Dim sFile As String
Dim sSFolder As String
Dim sDFolder As String

'This is Your File Name which you want to Copy
sFile = "*Template.2020.xlsm*"

'Change to match the source folder path
sSFolder = "\\account\man\"

'Change to match the destination folder path
sDFolder = "C:\Sales Reports\"

'Create Object
Set FSO = CreateObject("Scripting.FileSystemObject")

'Checking If File Is Located in the Source Folder
If Not FSO.FileExists(sSFolder & sFile) Then
    MsgBox "Specified File Not Found", vbInformation, "Not Found"
   
'Copying If the Same File is Not Located in the Destination Folder
ElseIf Not FSO.FileExists(sDFolder & sFile) Then
    FSO.CopyFile (sSFolder & sFile), sDFolder, True
    MsgBox "Specified File Copied Successfully", vbInformation, "Done!"
Else
    MsgBox "Specified File Already Exists In The Destination Folder", vbExclamation, "File Already Exists"
End If

End Sub

sp_AnswersTopicSeeAnswer See Answer
Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1845
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
2
August 21, 2020 - 4:23 pm
sp_Permalink sp_Print

Hi Howard,

You can also loop through the main folder subfolders:

Dim SbFld as object, FileObject as Object

For each SbFld in fso.GetFolder(sSFolder).SubFolders 'loop through subfolders

    For each FileObject in fso.GetFolder(SbFld).Files 'loop through files in each subfolder

           If FileObject.Name like "*Template*2020*xlsm" then

           'copy it, we found a file matching the template

           End IF    

   Next FileObject

Next SbFld

Avatar
Howard Cohen
Member
Members
Level 0
Forum Posts: 56
Member Since:
December 8, 2016
sp_UserOfflineSmall Offline
3
September 25, 2020 - 1:38 pm
sp_Permalink sp_Print sp_EditHistory

Sorry for only getting back to you now, but but been incredibly busy

 

I incoroprated your code with mine and get a compile error "Next without for"

 

Kindly amend code below

 

Sub sbCopyingAFile()

'Declare Variables
Dim FSO
Dim sFile As String
Dim sSFolder As String
Dim sDFolder As String
Dim SbFld As Object
Dim FileObject As Object
For Each SbFld In FSO.GetFolder(sSFolder).SubFolders 'loop through subfolders

For Each FileObject In FSO.GetFolder(SbFld).Files 'loop through files in each subfolder
If FileObject.Name Like "*Template*2020*xlsm" Then

'This is Your File Name which you want to Copy
'sFile = "*Template.2020.xlsm*"

'Change to match the source folder path

sSFolder = "\\account\man\"

'Change to match the destination folder path
sDFolder = "C:\Sales Reports\"

'Create Object
Set FSO = CreateObject("Scripting.FileSystemObject")

'Checking If File Is Located in the Source Folder
If Not FSO.FileExists(sSFolder & sFile) Then
MsgBox "Specified File Not Found", vbInformation, "Not Found"

'Copying If the Same File is Not Located in the Destination Folder
ElseIf Not FSO.FileExists(sDFolder & sFile) Then
FSO.CopyFile (sSFolder & sFile), sDFolder, True
MsgBox "Specified File Copied Successfully", vbInformation, "Done!"
Else
MsgBox "Specified File Already Exists In The Destination Folder", vbExclamation, "File Already Exists"
End If
Next FileObject

Next SbFld
End Sub 

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1845
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
4
September 25, 2020 - 5:20 pm
sp_Permalink sp_Print sp_EditHistory

There are many more issues in your code.

You have 2 lines with If...Then, but only 1 End If closing line.

Second issue:
move static parameters like sfile, sSFolder, sDFolder outside the loop, before loops. Makes no sense to set these parameters within loops, they will be set at every file found in those subfolders.

Another issue:

In order to use the file system object with FSO.GetFolder(sSFolder).SubFolders, it's a good idea to... create the object before using it, will not work otherwise. Before the loops, you have to create the FSO object.

 

And another one:

'Checking If File Is Located in the Source Folder
If Not FSO.FileExists(sSFolder & sFile) Then

This check is a nonsense. Because we use For Each FileObject In FSO.GetFolder(SbFld).Files, this means that we deal only with EXISTING files, checking an EXISTING file if it exists is simply redundant.

I can only guess that what you was trying to do is to see if the file naming structure corresponds to your convention sFile.
The code already does that in this line: If FileObject.Name Like "*Template*2020*xlsm" Then

Sub sbCopyingAFile()
'Declare Variables
Dim FSO
Dim sFile As String
Dim sSFolder As String
Dim sDFolder As String
Dim SbFld As Object
Dim FileObject As Object

'This is Your File Name which you want to Copy
sFile = "*Template*2020.xlsm*"
'Change to match the source folder path
sSFolder = "\\account\man\"
'Change to match the destination folder path
sDFolder = "C:\Sales Reports\"
'Create Object
Set FSO = CreateObject("Scripting.FileSystemObject")

For Each SbFld In FSO.GetFolder(sSFolder).SubFolders 'loop through subfolders
    For Each FileObject In FSO.GetFolder(SbFld).Files 'loop through files in each subfolder
        If FileObject.Name Like sFile Then
            'Copying If the Same File is Not Located in the Destination Folder
            If Not FSO.FileExists(sDFolder & FileObject.Name) Then
                FSO.CopyFile (FileObject.Path), sDFolder & FileObject.Name, True
                MsgBox "Specified File Copied Successfully", vbInformation, "Done!"
            Else
                MsgBox "Specified File Already Exists In The Destination Folder", vbExclamation, "File Already Exists"
            End If
        End If
    Next FileObject
Next SbFld
End Sub

Avatar
Howard Cohen
Member
Members
Level 0
Forum Posts: 56
Member Since:
December 8, 2016
sp_UserOfflineSmall Offline
5
September 25, 2020 - 8:39 pm
sp_Permalink sp_Print

Hi Catalin

 

This is beyond my VBA programming skills.

 

I am trying to copy all files within the network folder "\\account\man\" as well as its sub-folders that contain ""*Template*2020.xlsm*" for e.g. BR1 Sothern template Sales 2020.xlsm, BR2 Sothern template Sales 2020.xlsm etc and copy these to  "C:\Sales Reports\"

 

It would be appreciated if you would kindly provide me with the code to do this

Avatar
Philip Treacy
Admin
Level 10
Forum Posts: 1550
Member Since:
October 5, 2010
sp_UserOnlineSmall Online
6
October 6, 2020 - 9:51 am
sp_Permalink sp_Print sp_EditHistory

Hi Howard,

It's much easier to do this kind of thing directly in the command line.  Writing VBA to call FSO is just using the Windows Shell/Command Line anyway and way more work than it needs to be.

Start a Command Prompt and all you need is a line like this

xcopy "x:\man\*template*2020.xlsm" "c:\Sales Reports" /S /I /C

Where x:\man is a drive mapping to your \\account\man folder. 

I'm assuming you have the drive mapped? If not then using the UNC format "\\account\man\*template*2020.xlsm" should also work.

If you need to copy files periodically you can either place this line of code into a batch file or use VBA to call a Shell command

VBA Shell Function

Please read the XCOPY doco to understand how it works

https://docs.microsoft.com/en-.....ands/xcopy

Regards

Phil

sp_AnswersTopicAnswer
Answers Post
Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1845
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
7
October 6, 2020 - 2:45 pm
sp_Permalink sp_Print

It would be appreciated if you would kindly provide me with the code to do this

Hi Howard,

That's exactly what I did, you have in the previous message the corrected code, all you had to do is to paste it into your file and run it.

Avatar
Howard Cohen
Member
Members
Level 0
Forum Posts: 56
Member Since:
December 8, 2016
sp_UserOfflineSmall Offline
8
October 6, 2020 - 9:35 pm
sp_Permalink sp_Print

Many Thanks for your help

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Philip Treacy, Peter Venkatrao, QSolutions Group
Guest(s) 8
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 880
Purfleet: 414
Frans Visser: 346
David_Ng: 306
lea cohen: 237
Jessica Stewart: 219
A.Maurizio: 213
Aye Mu: 201
Hans Hallebeek: 185
Newest Members:
Kate Dyka
Kwaje Alfred Mogga
thong nguyen
Appiagyei Kofi Frimpong
Hilary Burchfield
Richie Wright
Adel Kock
Barbara Murray
Doug Milne
Siobhan Stringer
Forum Stats:
Groups: 3
Forums: 24
Topics: 6546
Posts: 28655

 

Member Stats:
Guest Posters: 49
Members: 32832
Moderators: 2
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel Office Scripts
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook

Sign up to our newsletter and join over 400,000
others who learn Excel and Power BI with us.

 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate
  • Sponsor Our Newsletter

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.