• 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
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Create Hyperlinked list of Files and Folders|VBA & Macros|Excel Forum|My Online Training Hub

You are here: Home / Create Hyperlinked list of Files and 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 & MacrosCreate Hyperlinked list of Files an…
sp_PrintTopic sp_TopicIcon
Create Hyperlinked list of Files and Folders
Avatar
David Bacon

New Member
Members
Level 0
Forum Posts: 1
Member Since:
June 8, 2021
sp_UserOfflineSmall Offline
1
June 8, 2021 - 2:10 am
sp_Permalink sp_Print

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

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1807
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
2
June 8, 2021 - 2:49 pm
sp_Permalink sp_Print sp_EditHistory

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

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1807
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
3
June 8, 2021 - 3:53 pm
sp_Permalink sp_Print

Or, you try a stronger version, that also handles file permission errors, does not add hyperlinks at all (a double click on the cell you want will open that file/folder using Shell), the array and resize method should be much faster than ListRows.Add method.

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Jessica Stewart, Dieneba NDIAYE, Mark Carlson, Calvin Richardson, Debi Morgan
Guest(s) 9
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
Debi Morgan
yashal minahil
Oluwadamilola Ogun
Yannik H
dectator mang
Francis Drouillard
Orlando Inocente
Jovitha Clemence
Maloxat Axmatovna
Ricardo Freitas
Forum Stats:
Groups: 3
Forums: 24
Topics: 6201
Posts: 27185

 

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

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • 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
 

Company

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

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.