Run DIR CMD From Macro

BadDogTitan

New Member
Joined
Sep 16, 2013
Messages
18
The command
Code:
dir /S /B /A:-S > FileList.xls
lists every folder, subfolder and file except for system files on a worksheet. I want the user to be able to select a folder, and obtain this result without having to run a command prompt.

Is there a way to run this command from VBA?

Thanks.
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
Welcome to the forum! While you could use Shell() to do that, it might be slow and not fully fill the text file before other code ran. Of course sending ascii test to a binary file would not work.

Maybe this example will better suit your goal. Change the command line switches and such to suit.
Code:
Sub DirStdOut()
  Dim s As String, a() As String
  ' /b = bare file listing, /s = search subfolders, /c = open command shell, run command and then close shell.
  ' /a:-d means list files only and not subfolders
  s = CreateObject("Wscript.Shell").exec("cmd /c dir x:\test\*.* /a:d /b").StdOut.ReadAll
  a() = Split(s, vbCrLf)
  With Range("A1")
    .EntireColumn.Clear
    .Resize(UBound(a)).Value = WorksheetFunction.Transpose(a)
  End With
End Sub
 
Last edited:
Upvote 0
There's a guy who knows his stuff. No 50-line long set of code, having to set 3 Objects, stepping through reading folders and subfolders. Just a straight-to-the point, here's a good, easy way to do it.

Hats off to Mr. Hobson.
 
Upvote 0
An XLS file is NOT a TXT file. You can pipe the text string to an XLS file but when you open it, it will show it as corrupt. Excel may or may not then crash. My tests shows about 1 in 5 would crash.

Here it is should you want to try your method.
VBA Code:
Sub Main()
  Dim s As String
  s = Get_Folder(ThisWorkbook.Path, "Delete the value in ""Folder name:"" to Choose the Parent Folder") & "\"
  s = "cmd /c dir " & """" & s & """" & " /S /B /A:-S > " & """" & s & "FileList.xls" & """"
  'Debug.Print s
  CreateObject("WScript.Shell").Exec s
End Sub


Function Get_Folder(Optional FolderPath As String, _
  Optional HeaderMsg As String) As String
    With Application.FileDialog(msoFileDialogFolderPicker)
        If FolderPath = "" Then
          .InitialFileName = Application.DefaultFilePath
          Else
          .InitialFileName = FolderPath
        End If
        .Title = HeaderMsg
        If .Show = -1 Then
            Get_Folder = .SelectedItems(1)
        Else
            Get_Folder = ""
        End If
    End With
End Function
If it were me, I would use the method that I posted earlier and send that output to a new workbook and then save it in the preferred format: XLS, XLSX, XLSM, etc. Of course the function in this post would be used too to get your folder selection option.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,183
Members
453,020
Latest member
Mohamed Magdi Tawfiq Emam

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