|
楼主 |
发表于 2018-1-14 16:35
|
显示全部楼层
筛选只是PDF和XLS的文件可以有,逐级显示文件夹路径没有意义,只写了一个筛选文件类型的,并显示该文件所在的文件夹。
想显示每一级文件夹,可以自己用split获取,按“\”分割然后循环就行了,在该程序中,获取最后一列可以用cells(r,columns.count).end(xltoleft).column,其中r是最后一行行号。
获取指定文件夹及其子文件夹下所有文件 副本.zip
(26.9 KB, 下载次数: 434)
Sub allfiles()
Set fdo = Application.FileDialog(msoFileDialogFolderPicker)
If fdo.Show = -1 Then
pth = fdo.SelectedItems(1)
Else
MsgBox "您没有选择文件夹!按『确定』键结束", vbCritical
Exit Sub
End If
UserForm1.Show 0
DoEvents
Application.ScreenUpdating = False
With ActiveSheet
.UsedRange.Clear
.Cells(1, 1) = "文件序号"
.Cells(1, 2) = "文件名称"
.Cells(1, 3) = "创建日期"
.Cells(1, 4) = "修改日期"
.Cells(1, 5) = "文件类型"
.Cells(1, 6) = "文件大小"
.Cells(1, 7) = "文件路径"
Getfd (pth)
r = .Range("b" & Rows.Count).End(3).Row
.Range("a1:f" & r).Borders.LineStyle = xlContinuous
.Range("a1:f" & r).Borders.Weight = xlThin
End With
Application.ScreenUpdating = True
Unload UserForm1
MsgBox "文件已全部获取!点『确定』键结束"
End Sub
Sub Getfd(ByVal pth)
Set fso = CreateObject("scripting.filesystemobject")
Set ff = fso.getfolder(pth)
i = 1
For Each f In ff.Files
If InStr("PDF/XLS", UCase(Mid(f.Name, InStrRev(f.Name, ".", -1, 1) + 1))) Then
r = Cells(Rows.Count, 1).End(3).Offset(1).Row
Cells(r, 1) = i: i = i + 1
With Cells(r, 2)
.Value = f
.Hyperlinks.Add Anchor:=Cells(r, 2), Address:=.Value, TextToDisplay:=Split(.Value, "\")(UBound(Split(.Value, "\")))
End With
Cells(r, 3) = f.DateCreated
Cells(r, 4) = f.DateLastModified
Cells(r, 5) = Mid(f.Name, InStrRev(f.Name, ".", -1, 1) + 1)
Cells(r, 6) = Format(f.Size / 1048576, "0.00MB")
With Cells(r, 7)
.Value = ff.Path
.Hyperlinks.Add Anchor:=Cells(r, 7), Address:=.Value, TextToDisplay:=.Value
End With
End If
Next
For Each fd In ff.subfolders
Getfd (fd)
Next
End Sub
|
|