Get the list of files from a folder based on cell A1

Lakabi

New Member
Joined
Jun 11, 2011
Messages
26
Hi all
I would like to have to have the list of files from folder "X" including subfolders ( the folder is on the network), in column B, and from folder "Y" including subfolders ( the folder is on the network) in column C based on the criteria in cell A1. I am looking for all files which names starts with the string entered in A1. Ex. if A1= 12345, then list all files from folder X and folder Y, which file names start with 12345 (ex file "12345 abc.pdf"). Perhaps list only the file names as hyperlinks. Also I would need the list to update soon as the value or string in A1 is changed. Using Excel 2003.
Thanks in advance.
 
The TestCreateFileListAndHyperlinks code didn't have to be modified to have the hyperlinks output to the same column. Setting OutputCol and HyperlinkCol as the same column letter will work. I will leave the option to have a two column output and no hyperlink output functionality available for future uses. I did tweak it slightly to be more efficient if the output and hyperlink column were the same.

The below will only clear content from row 2 to row 31. Though you have to be careful placing data under the output since the filter is applied automatically when A1 changes there is the potential for an overwrite.

Code:
Sub TestCreateFileListAndHyperlinks( _
                Criteria As String, _
                SearchPath As String, _
                IncludeSubfolders As Boolean, _
                OutputCol As String, _
                Optional HyperlinkCol As String)
                
    Dim FileNamesList As Variant
    Dim startDir As String
    Dim oCol As Integer
    Dim hCol As Integer
    Dim i As Integer
    Dim addHL As Boolean
    '// ———————————————————————————————————————————————————————————————————————
    '// Check if directory exists
    If Dir(SearchPath, vbDirectory) = "" Then
        MsgBox "PATH:" & SearchPath & " — doesn't exist or is not accessible"
        Exit Sub
    End If
    If Not IsMissing(HyperlinkCol) And HyperlinkCol <> "" Then addHL = True
    oCol = Columns(OutputCol).Column
    If addHL Then hCol = Columns(HyperlinkCol).Column
    '// ———————————————————————————————————————————————————————————————————————
    '// Directory and File Search Operations
    '//
    '// Store the Current Directory
    startDir = CurDir()
    '// Set the search directory
    ChDir SearchPath
    '// Create file list that matches Criteria with seperate Function
    FileNamesList = CreateFileList(Criteria & "*.*", IncludeSubfolders)
    '// Restore current current Directory to previous path
    ChDir startDir
    
    '// ———————————————————————————————————————————————————————————————————————
    '// Clear Contents of Output Row Excluding First Row
    Range(Cells(2, oCol), Cells(31, oCol)).ClearContents
    If addHL And oCol <> hCol Then _
        Range(Cells(2, hCol), Cells(31, hCol)).ClearContents
    '// ———————————————————————————————————————————————————————————————————————
    '// Results Output
    '//
    '// Set Default value if criteria was not found in search folder
    '//  will be overwritten if criteria finds match
    Cells(2, Columns(OutputCol).Column).Formula = "No Match to Criteria"
    '// Error handling to prevent errors if array is empty
    On Error Resume Next
    For i = 1 To UBound(FileNamesList)
        '// Path Output
        If oCol <> hCol then
            Cells(i + 1, oCol).Formula = FileNamesList(i)
        End If
       If addHL Then
        '// Hyperlink Output
        ActiveSheet.Hyperlinks.Add _
            Anchor:=Cells(i + 1, hCol), _
            Address:=FileNamesList(i), _
            TextToDisplay:= _
                Mid(FileNamesList(i), InStrRev(FileNamesList(i), "\") + 1)
        End If
    Next i
    On Error GoTo 0
End Sub

Also your modification look fine.
 
Upvote 0

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
Rob
Thanks again. Setting the OutputCol and HyperlinkCol into the same column is neat. Looks and functioning very nice. Thanks for the warning, I was thinking about that too, but at this point 30 rows already a big stretch for now. I never had named files (this is by process or item) more then 11 times with the same item/process. I want to incorporate this code in my report/lookup file which over the years grew fairly complex (of course this is from my point of view), and the space (realestate on the screen) is getting limited. I want to keep it simplest and quickest possible the lookup and reporting of item/process.

Getting back to the code, applying that to the folders on my network, I am still having trouble with the issue that the search reverts back into "MyDocuments" yet the path is set to "Z:\SHARED".

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target.Address = "$A$1" Then
    '
        TestCreateFileListAndHyperlinks _
                    Criteria:=Range("A1").Value, _
                    SearchPath:="Z:\SHARED", _
                    IncludeSubfolders:=True, _
                    OutputCol:="B", _
                    HyperlinkCol:="B"
        TestCreateFileListAndHyperlinks _
                    Criteria:=Range("A1").Value, _
                    SearchPath:="C:\FOLDER2", _
                    IncludeSubfolders:=True, _
                    OutputCol:="C", _
                    HyperlinkCol:="C"
        TestCreateFileListAndHyperlinks _
                    Criteria:=Range("A1").Value, _
                    SearchPath:="C:\FOLDER3", _
                    IncludeSubfolders:=True, _
                    OutputCol:="D", _
                    HyperlinkCol:="D"
        TestCreateFileListAndHyperlinks _
                    Criteria:=Range("A1").Value, _
                    SearchPath:="C:\FOLDER4", _
                    IncludeSubfolders:=True, _
                    OutputCol:="E", _
                    HyperlinkCol:="E"
    End If
End Sub

Thanks.
 
Upvote 0
As I said before I don't have Excel 2003 so I can't use FileSearch therefore, I can't test it. I think that the network drive problem stems from using CurDir without providing it a drive letter. Rather than deal with changing the current directory it would better to pass the path string as an argument. Find below the revised version.

Code:
Sub TestCreateFileListAndHyperlinks( _
                Criteria As String, _
                SearchPath As String, _
                IncludeSubfolders As Boolean, _
                OutputCol As String, _
                Optional HyperlinkCol As String)
                
    Dim FileNamesList As Variant
    Dim oCol As Integer
    Dim hCol As Integer
    Dim i As Integer
    Dim addHL As Boolean
    '// ———————————————————————————————————————————————————————————————————————
    '// Check if directory exists
    If Dir(SearchPath, vbDirectory) = "" Then
        MsgBox "PATH:" & SearchPath & " — doesn't exist or is not accessible"
        Exit Sub
    End If
    If Not IsMissing(HyperlinkCol) And HyperlinkCol <> "" Then addHL = True
    oCol = Columns(OutputCol).Column
    If addHL Then hCol = Columns(HyperlinkCol).Column
    '// ———————————————————————————————————————————————————————————————————————
    '// Directory and File Search Operations
    '//
    '// Create file list that matches Criteria with seperate Function
    FileNamesList = CreateFileList(Criteria & "*.*",  [COLOR="red"]SearchPath,[/COLOR] IncludeSubfolders)
    
    '// ———————————————————————————————————————————————————————————————————————
    '// Clear Contents of Output Row Excluding First Row
    '// Clear Contents of Output Row Excluding First Row
    Range(Cells(2, oCol), Cells(30, oCol)).ClearContents
    If addHL And oCol <> hCol Then _
        Range(Cells(2, hCol), Cells(30, hCol)).ClearContents
    '// ———————————————————————————————————————————————————————————————————————
    '// Results Output
    '//
    '// Set Default value if criteria was not found in search folder
    '//  will be overwritten if criteria finds match
    Cells(2, Columns(OutputCol).Column).Formula = "No Match to Criteria"
    '// Error handling to prevent errors if array is empty
    On Error Resume Next
    For i = 1 To UBound(FileNamesList)
        '// Path Output
        Cells(i + 1, oCol).Formula = FileNamesList(i)
       If addHL Then
        '// Hyperlink Output
        ActiveSheet.Hyperlinks.Add _
            Anchor:=Cells(i + 1, hCol), _
            Address:=FileNamesList(i), _
            TextToDisplay:= _
                Mid(FileNamesList(i), InStrRev(FileNamesList(i), "\") + 1)
        End If
    Next i
    On Error GoTo 0
End Sub

Code:
Function CreateFileList( _
                    FileFilter As String, _
                    [COLOR="red"]SearchFolder As String, _[/COLOR]
                    IncludeSubfolders As Boolean) As Variant
' returns the full filename for files matching
' the filter criteria in the passed folder
Dim FileList() As String, FileCount As Long
    CreateFileList = ""
    Erase FileList
    If FileFilter = "*.*" Then FileFilter = "*.*" ' all files
    With Application.FileSearch
        .NewSearch
        .LookIn = [COLOR="Red"]SearchFolder[/COLOR]
        .Filename = FileFilter
        .SearchSubFolders = IncludeSubfolders
        .FileType = msoFileTypeAllFiles
        If .Execute(SortBy:=msoSortByFileName, _
            SortOrder:=msoSortOrderAscending) = 0 Then Exit Function
        ReDim FileList(.FoundFiles.Count)
        For FileCount = 1 To .FoundFiles.Count
            FileList(FileCount) = .FoundFiles(FileCount)
        Next FileCount
        .FileType = msoFileTypeExcelWorkbooks ' reset filetypes
    End With
    CreateFileList = FileList
    Erase FileList
End Function
 
Upvote 0
"FileSearch" is it. The code is on the fly. THANKS.
My file looks almost "perfect".
For all those who following, here is the complete code. In red is the path for my test network folder.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target.Address = "$A$1" Then
    '
        TestCreateFileListAndHyperlinks _
                    Criteria:=Range("A1").Value, _
                    SearchPath:="[COLOR=Red]Z:\Seagate[/COLOR]", _
                    IncludeSubfolders:=True, _
                    OutputCol:="B", _
                    HyperlinkCol:="B"
        TestCreateFileListAndHyperlinks _
                    Criteria:=Range("A1").Value, _
                    SearchPath:="C:\FOLDER2", _
                    IncludeSubfolders:=True, _
                    OutputCol:="C", _
                    HyperlinkCol:="C"
        TestCreateFileListAndHyperlinks _
                    Criteria:=Range("A1").Value, _
                    SearchPath:="C:\FOLDER3", _
                    IncludeSubfolders:=True, _
                    OutputCol:="D", _
                    HyperlinkCol:="D"
        TestCreateFileListAndHyperlinks _
                    Criteria:=Range("A1").Value, _
                    SearchPath:="C:\FOLDER4", _
                    IncludeSubfolders:=True, _
                    OutputCol:="E", _
                    HyperlinkCol:="E"
    End If
End Sub



Sub TestCreateFileListAndHyperlinks( _
                Criteria As String, _
                SearchPath As String, _
                IncludeSubfolders As Boolean, _
                OutputCol As String, _
                Optional HyperlinkCol As String)
                
    Dim FileNamesList As Variant
    Dim oCol As Integer
    Dim hCol As Integer
    Dim i As Integer
    Dim addHL As Boolean
    '// ———————————————————————————————————————————————————————————————————————
    '// Check if directory exists
    If Dir(SearchPath, vbDirectory) = "" Then
        MsgBox "PATH:" & SearchPath & " — doesn't exist or is not accessible"
        Exit Sub
    End If
    If Not IsMissing(HyperlinkCol) And HyperlinkCol <> "" Then addHL = True
    oCol = Columns(OutputCol).Column
    If addHL Then hCol = Columns(HyperlinkCol).Column
    '// ———————————————————————————————————————————————————————————————————————
    '// Directory and File Search Operations
    '//
    '// Create file list that matches Criteria with seperate Function
    FileNamesList = CreateFileList(Criteria & "*.*", SearchPath, IncludeSubfolders)
    
    '// ———————————————————————————————————————————————————————————————————————
    '// Clear Contents of Output Row Excluding First Row
    '// Clear Contents of Output Row Excluding First Row
    Range(Cells(2, oCol), Cells(30, oCol)).ClearContents
    If addHL And oCol <> hCol Then _
        Range(Cells(2, hCol), Cells(30, hCol)).ClearContents
    '// ———————————————————————————————————————————————————————————————————————
    '// Results Output
    '//
    '// Set Default value if criteria was not found in search folder
    '//  will be overwritten if criteria finds match
    Cells(2, Columns(OutputCol).Column).Formula = "No Match to Criteria"
    '// Error handling to prevent errors if array is empty
    On Error Resume Next
    For i = 1 To UBound(FileNamesList)
        '// Path Output
        Cells(i + 1, oCol).Formula = FileNamesList(i)
       If addHL Then
        '// Hyperlink Output
        ActiveSheet.Hyperlinks.Add _
            Anchor:=Cells(i + 1, hCol), _
            Address:=FileNamesList(i), _
            TextToDisplay:= _
                Mid(FileNamesList(i), InStrRev(FileNamesList(i), "\") + 1)
        End If
    Next i
    On Error GoTo 0
End Sub


Function CreateFileList( _
                    FileFilter As String, _
                    SearchFolder As String, _
                    IncludeSubfolders As Boolean) As Variant
' returns the full filename for files matching
' the filter criteria in the passed folder
Dim FileList() As String, FileCount As Long
    CreateFileList = ""
    Erase FileList
    If FileFilter = "*.*" Then FileFilter = "*.*" ' all files
    With Application.FileSearch
        .NewSearch
        .LookIn = SearchFolder
        .Filename = FileFilter
        .SearchSubFolders = IncludeSubfolders
        .FileType = msoFileTypeAllFiles
        If .Execute(SortBy:=msoSortByFileName, _
            SortOrder:=msoSortOrderAscending) = 0 Then Exit Function
        ReDim FileList(.FoundFiles.Count)
        For FileCount = 1 To .FoundFiles.Count
            FileList(FileCount) = .FoundFiles(FileCount)
        Next FileCount
        .FileType = msoFileTypeExcelWorkbooks ' reset filetypes
    End With
    CreateFileList = FileList
    Erase FileList
End Function
Thank you much for your help, I really appreciated.

Now two of the folder (perhaps maybe "Folder3" and "Folder4") search I need not based the beginning of the string from A1 but to look for the string in the file name. Also this would be from reference cell B1 which would be different value/string from A1. Ex. search string "item10" would be found in file names like "file# item1.pdf".
This is makes me think how could I capture the changes in cell A1 and would be for B1, from an other cell, and not entering directly in the cell and hit "enter".
I did tried to reference like cellA1 =E1, but changes in E1 did not triggered the file search, yet the value did changed in A1.

Looking forward to your response.
 
Last edited:
Upvote 0
I think it might be better if the criteria and path were accessible on the sheet. See the below example.
Excel Workbook
ABCDE
1FolderZ:\SeagateC:\FOLDER2C:\FOLDER3C:\FOLDER4
2Criteria401*.*402*.*403*.pdf*404*.xls
31401Text1.txt402Text1.txt403Doc.pdf404ss.xls
42401Text2.txt402Text2.txt404Item.xls
53401Doc.pdf402Doc.pdfFile404Temp.xls
64401ss.xls402ss.xls
75401Item.xls402Item.xls
86
...

This would provide greater granularity on what was searched for a particular folder and would allow the use custom wildcards such as
prefix "401*.*"
Prefix and file type "401*.pdf"
In file name "*401*.*"​
The code would only have to adjusted slightly to get this to work. Is this an approach would like to take?
 
Upvote 0
Looks neat and flexible, but I am not sure about the file type. The criteria is dynamic, and it is always a specific string (the range is "unlimited" variation between numbers and letters).

Here is the layout/works:

I have four folders (for now): FOLDER1, FOLDER2, FOLDER3, FOLDER4.

First two folders(it may be 3 or 4 in the future): FOLDER1 and FOLDER2 contains group of files which names all starts with the same string. Ex there will be a group of files (reports from different dates, and different processes) that will start with 123, 46758, or 938... etc. So when I search for 46758 ("Item1"), it will give me all the files that starts with 46758. These files types can be pdf, doc, xls, tif, jpg.

The two other folders (this is probably will become four different folders in the future) : FOLDER3 and FOLDER4 will have files (pdf, xls, tif, dwg, doc) which names contains a string (different from the above string) of a mixed letters and numbers. Ex. if search criteria "b11_45-x" ("Item2") it will give me the list of files that contains "b11_45-x" in the file name regardless if "b11_45-x" is the beginning, middle of end of the file name.

Each FOLDER contains files for a specific category. "Item1" is the governing number and "Item2" is associated with "Item1" . Like "Item1" would be the primary key.

So when I enter "item1" on my sheet this would invoke the lists from "FOLDER1" and "FOLDER2" and also will invoke "item2" (cell B1 or maybe A2) associated with it, which eventually would invoke the list of files from "FOLDER3" and "FOLDER4".

I hope that my explanation is clear enough. What would you suggest?
 
Last edited:
Upvote 0
I am not sure that I communicated it well but the filetype was just meant as an example of the flexibility. The main point I was trying to make is that you could make the filter be anything and adjustable for each folder. So if you want a prefix search item1*.* for folders 1 & 2 and in name search *item1*.* for folders 3 & 4 it is all exposed at the sheet level.
 
Upvote 0
Here is the code for the alternative method that I recommended. The change range it checks is resizable but is currently set for columns B to E. If you need to do a in file name search just add a '*' before the search item (ex. *item1) the '*.*' will still be added to the end automatically.

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Application.EnableEvents = False
    Application.ScreenUpdating = False
    On Error GoTo EarlyExit
    If Not Intersect(Target, Range("[B][COLOR="Red"]B1:E2[/COLOR][/B]")) Is Nothing Then
        Dim cell As Range
        For Each cell In Target
            If Not Intersect(cell, Range("[B][COLOR="Red"]B1:E2[/COLOR][/B]")) Is Nothing Then
                TestCreateFileListAndHyperlinks _
                    Criteria:=Cells(2, cell.Column).Value, _
                    SearchPath:=Cells(1, cell.Column).Value, _
                    IncludeSubfolders:=True, _
                    OutputCol:=cell.Column, _
                    HyperlinkCol:=cell.Column
            End If
        Next cell
    End If
EarlyExit:
    Application.EnableEvents = True
    Application.ScreenUpdating = True
End Sub
Code:
Sub TestCreateFileListAndHyperlinks( _
                Criteria As String, _
                SearchPath As String, _
                IncludeSubfolders As Boolean, _
                OutputCol As Variant, _
                Optional HyperlinkCol As Variant)
                
    Dim FileNamesList As Variant
    Dim oCol As Integer         'Text Output Column Number
    Dim hCol As Integer         'Hyperlink Output Column
    Dim i As Integer            'Loop Counter
    Dim addHL As Boolean        'Hyperlink column passed
    '// ———————————————————————————————————————————————————————————————————————
    '// Output Range
    '// First output Row
    Const START_ROW = 3
    '// Clear to row
    Const LAST_ROW = [B][COLOR="Red"]30[/COLOR][/B]
    '// ———————————————————————————————————————————————————————————————————————
    '// Output column
    oCol = Columns(OutputCol).Column
    '// Hyperlink column
    If Not IsMissing(HyperlinkCol) And HyperlinkCol <> "" Then addHL = True
    If addHL Then hCol = Columns(HyperlinkCol).Column
    '// ———————————————————————————————————————————————————————————————————————
    '// Directory and File Search Operations
    '//
    '// Create file list that matches Criteria with seperate Function
    FileNamesList = CreateFileList(Criteria & "*.*", SearchPath, IncludeSubfolders)
    '// ———————————————————————————————————————————————————————————————————————
    '// Clear Contents of Output Row Excluding First Row
    Range(Cells(START_ROW, oCol), Cells(LAST_ROW, oCol)).ClearContents
    If addHL And oCol <> hCol Then _
        Range(Cells(START_ROW, hCol), Cells(LAST_ROW, hCol)).ClearContents
    '// ———————————————————————————————————————————————————————————————————————
    '// Check if directory exists
    If Dir(SearchPath, vbDirectory) = "" Then
        MsgBox SearchPath & vbCr & vbCr & "Doesn't exist or is not accessible"
        Exit Sub
    End If
    '// ———————————————————————————————————————————————————————————————————————
    '// Results Output
    '//
    '// Set Default value if criteria was not found in search folder
    '//  will be overwritten if criteria finds match
    Cells(START_ROW, Columns(OutputCol).Column).Formula = "No Criteria Match"
    '// Error handling to prevent errors if array is empty
    On Error Resume Next
    For i = 1 To UBound(FileNamesList)
        '// Path Output
        If oCol <> hCol Then
            Cells(i + 1, oCol).Formula = FileNamesList(i)
        End If
       If addHL Then
        '// Hyperlink Output
        ActiveSheet.Hyperlinks.Add _
            Anchor:=Cells((i - 1) + START_ROW, hCol), _
            Address:=FileNamesList(i), _
            TextToDisplay:= _
                Mid(FileNamesList(i), InStrRev(FileNamesList(i), "\") + 1)
        End If
    Next i
    On Error GoTo 0
End Sub
 
Upvote 0
Rob,

You communicated well, it is me.
Yes you are correct, it would be more flexible to have access the variables from the sheet itself. What I am still unsure of when I will share the file,the variables (Folder, Criteria) my be overwritten by users, and maybe safer within the code. Of course I can protect the cells, and perhaps move these cells (B1,B2,C1...E2, in your example) away from the actual working area, like to cells DA1,DA2...
Bottom line your suggestion is very good.
Looking forward to the new code.
Thanks.

By the time I finished my response your code is already posted.
Thanks much.
 
Upvote 0
Rob,

It would work if you could link the entry's in cells B2 thru E2 (from your example) from cells W1 thru Z1. Ex instead to typing the string in each cell from B2 thru E2, like 401*.* or *404*.*, I could have link like:
"result from cell W1"*.*
or
*"result from cell Z1"*.*

In this example cell W1=401, and cell Z1=404. These values can be results of a function like "VLOOKUP".
I did ignored columns C and D in this example.
Excel Workbook
ABCDE
1FolderZ:\SeagateC:\FOLDER2C:\FOLDER3C:\FOLDER4
2Criteria"result from cell W1"*.*402*.*403*.pdf*"result from cell Z1"*.*
31401Text1.txt402Text1.txt403Doc.pdf404ss.xls
42401Text2.txt402Text2.txt 404Item.xls
53401Doc.pdf402Doc.pdf File404Temp.xls
64401ss.xls402ss.xls
75401Item.xls402Item.xls
86
...
 
Upvote 0

Forum statistics

Threads
1,224,530
Messages
6,179,373
Members
452,907
Latest member
Roland Deschain

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