Create File Directory Within Excel

Ottsel

Board Regular
Joined
Jun 4, 2022
Messages
167
Office Version
  1. 365
Platform
  1. Windows
I've been using a bat file to create an updated directory list of all my file names within a certain drive and folder, then I use another macro to extract and filter the data. The issue is for some reason I have to be within that folder, use that bat file to generate the list (which it disguises itself as excel file) to have it correctly make the list.
The Bat file:
Rich (BB code):
G:
CD Records
dir /b /s >extractlist.xls

Then upon opening the extractlist it'll appear as such:
1678219170829.png


It puts everything in column A, which is fine and it contains over 5000 rows of data. This method is fast, but the main issue is if you forget to update the directory and use the other macro you encounter errors, which is unfortunate, as it takes a while for it to run everything. I attempted to have VBA run the bat file for me, but again you have to be within the folder, click it, generate the list while in the Records folder for it to work.

If you know a way to get a list to generate all the folder names, sub-folders within the Drive and Folder destination and files I would greatly appreciate any insight on this.

Here's the VBA code I use to extract the list, it generates the files on my desktop instead of the G drive > Records folder.
VBA Code:
Sub UpdateDirectory_test()
    Dim wb As Workbook
    Dim sourcePath As String
    Dim extractList As String

    sourcePath = "G:\Records\"
    extractList = sourcePath & "extractlist.xls"

    Dim oldWarning As Long
    oldWarning = Application.DisplayAlerts
    Application.DisplayAlerts = False

    Shell sourcePath & "Extract Jobcard List.bat"
    Application.Wait (Now + TimeValue("0:00:03"))

    Application.DisplayAlerts = oldWarning

    Set wb = Workbooks.Open(extractList)

    wb.Sheets(1).Range("A1:A" & wb.Sheets(1).Range("A1").End(xlDown).row).Copy _
        Destination:=ThisWorkbook.Sheets("Directory").Range("A1")

    wb.Close False
End Sub
 

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
This should give you a list of all files and subfolders starting at a given folder:

VBA Code:
Sub GetFolders()
Dim Root As String, dic As Object

    Root = "C:\TopFolder\"
    Set dic = CreateObject("Scripting.Dictionary")
    dic.Add Root, 0
    Call recur(Root, dic)
    Range("A1").Resize(dic.Count).Value = WorksheetFunction.Transpose(dic.keys)
    
End Sub

Sub recur(ByVal FolderName, ByRef dic)
Dim f As Variant, sf As Variant

    With CreateObject("Scripting.FileSystemObject").GetFolder(FolderName)
        For Each f In .Files
            dic.Add f.Path, f.Type
        Next f
        For Each sf In .SubFolders
            dic.Add sf.Path, "Folder"
            Call recur(sf.Path, dic)
        Next sf
    End With
    
End Sub
 
Upvote 1
Solution
This should give you a list of all files and subfolders starting at a given folder:

VBA Code:
Sub GetFolders()
Dim Root As String, dic As Object

    Root = "C:\TopFolder\"
    Set dic = CreateObject("Scripting.Dictionary")
    dic.Add Root, 0
    Call recur(Root, dic)
    Range("A1").Resize(dic.Count).Value = WorksheetFunction.Transpose(dic.keys)
   
End Sub

Sub recur(ByVal FolderName, ByRef dic)
Dim f As Variant, sf As Variant

    With CreateObject("Scripting.FileSystemObject").GetFolder(FolderName)
        For Each f In .Files
            dic.Add f.Path, f.Type
        Next f
        For Each sf In .SubFolders
            dic.Add sf.Path, "Folder"
            Call recur(sf.Path, dic)
        Next sf
    End With
   
End Sub
Thank you Eric! This is perfect.
 
Upvote 0

Forum statistics

Threads
1,214,980
Messages
6,122,563
Members
449,088
Latest member
Motoracer88

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