New Member
June 8, 2021
Hi,
The code below works and produces a list of all files and folders but will not exceed 32767 rows in the excel output table - when it reaches this point the vba stops running with the error: "Run-time error '1004' Application-defined or Object-defined error" stopping at line:
NewRow.Cells(1, 2).Hyperlinks.Add Anchor:=NewRow.Cells(1, 2), Address:=StartingFolder.Path & “\” & CurrentFilename, TextToDisplay:=CurrentFilename
Code below.
Option Explicit
Public FSO As New FileSystemObject
Private FileType As Variant
Sub ListHyperlinkFilesInSubFolders()
' Written by Philip Treacy, http://www.myonlinetraininghub.....or/philipt
' My Online Training Hub http://www.myonlinetraininghub.....Subfolders
' May 2014
Dim StartingCell As String 'Cell where hyperlinked list starts
Dim FSOFolder As Folder, LinksTable As ListObject
Dim RootFolder As String
Dim ListObject As Long
Dim DataBodyRange As Long
Dim Count As Long
Application.ScreenUpdating = False
'clear the table
Set LinksTable = ActiveSheet.ListObjects(1)
If Not LinksTable.DataBodyRange Is Nothing Then LinksTable.DataBodyRange.Delete
'Ask for folder to list files from
With Application.FileDialog(msoFileDialogFolderPicker)
.InitialFileName = Application.DefaultFilePath & "\"
.Title = "Please select folder to list files from"
.Show
'If a folder has been selected
If .SelectedItems.Count <> 0 Then
RootFolder = .SelectedItems(1)
Set FSOFolder = FSO.GetFolder(RootFolder)
'Ask what type of files to look for
FileType = Application.InputBox("* and ? wildcards are valid " & vbCrLf & vbCrLf & " e.g. .xls* to list XLS, XLSX and XLSM" _
& vbCrLf & vbCrLf & "??st.* to list West.xlsx and East.xlsx" & vbCrLf & vbCrLf & "Just click OK to list all files.", _
"What type of files do you want to list?", "")
If FileType = False Then 'Cancel pressed
MsgBox "Process Cancelled"
Exit Sub
ElseIf FileType = vbNullString Then 'Nothing entered and OK pressed
FileType = "*.*"
End If
' Call recursive sub to list files
ListFilesInSubFolders FSOFolder, LinksTable
'Autofit the columns containing our results
LinksTable.Range.Columns.AutoFit
Else
'If no folder selected, admonish user for wasting CPU cycles 🙂
MsgBox "No folder selected.", vbExclamation
End If
End With
Application.ScreenUpdating = True
End Sub
Sub ListFilesInSubFolders(StartingFolder As Scripting.Folder, LinksTable As ListObject)
' Written by Philip Treacy, http://www.myonlinetraininghub.....or/philipt
' My Online Training Hub http://www.myonlinetraininghub.....Subfolders
' May 2014
' Lists all files specified by FileType in all subfolders of the StartingFolder object.
' This sub is called recursively
Dim CurrentFilename As String
Dim OffsetRow As Long
Dim Range As Long
Dim TargetFiles As String, NewRow As Range
Dim SubFolder As Scripting.Folder
Dim ListRows As Long
Dim Count As Long
'Get the first file, look for Normal, Read Only, System and Hidden files
'TargetFiles = StartingFolder.Path & "\" & FileType
TargetFiles = StartingFolder.Path & "\" & Application.PathSeparator & FileType
CurrentFilename = Dir(TargetFiles, 7)
Do While CurrentFilename <> ""
LinksTable.ListRows.Add
Set NewRow = LinksTable.ListRows(LinksTable.ListRows.Count).Range
'Write name of folder to cell
NewRow.Cells(1, 1).Hyperlinks.Add Anchor:=NewRow.Cells(1, 1), Address:=StartingFolder.Path, TextToDisplay:=StartingFolder.Path
'Create the file hyperlink
NewRow.Cells(1, 2).Hyperlinks.Add Anchor:=NewRow.Cells(1, 2), Address:=StartingFolder.Path & "\" & CurrentFilename, TextToDisplay:=CurrentFilename
'Get the next file
CurrentFilename = Dir
Loop
' For each SubFolder in the current StartingFolder call ListFilesInSubFolders (recursive)
' The sub continues to call itself for each and every folder it finds until it has
' traversed all folders below the original StartingFolder
For Each SubFolder In StartingFolder.SubFolders
ListFilesInSubFolders SubFolder, LinksTable
Next SubFolder
End Sub
Let me know what I am missing here.
Thanks
David
Power Query
Power Pivot
Xtreme Pivot Tables
Excel for Decision Making
Excel for Finance
Excel Analysis Toolpak
Power BI
Excel
Word
Outlook
Excel Expert
Excel Customer Service
PowerPoint
November 8, 2013
You have reached a limit in excel, but not the Integer limit as I initially thought, it's the maximum hyperlinks limit you have reached: 65530 hyperlinks.
You can see the limitation here:
https://support.microsoft.com/.....9d656771c3
A workaround might be to write only file hyperlinks, not folder hyperlinks, you will be able to write 65530 rows in the output table, instead of just 32767:
'Write name of folder to cell
NewRow.Cells(1, 1).Value=StartingFolder.Path 'instead of hyperlink
'Create the file hyperlink
NewRow.Cells(1, 2).Hyperlinks.Add Anchor:=NewRow.Cells(1, 2), Address:=StartingFolder.Path & "\" & CurrentFilename, TextToDisplay:=CurrentFilename
1 Guest(s)