List excel files with embedded objects inside

MarcMermans

New Member
Joined
Dec 4, 2012
Messages
7
Hello,

Is it possible to do a seach in a lot of excel files (>500) to find the excel files wich have an embedded objects inside.
If so how can I do this with VBA ?


Best regards.

Marc
 

Excel Facts

What is the last column in Excel?
Excel columns run from A to Z, AA to AZ, AAA to XFD. The last column is XFD.
try this.
the code will let you select folder where your excel files are located and the code will loop through all files and return you the count of msoLinkedOLEObject in each excel workbook in folder.

i think this is what you want.
all the best.

Public Function ShowFolderList()
'Reference it to MS Form x.x object lib

Dim wb As Workbook
Dim i As Shape
Dim fld As String
Dim fs, f, f1, fc
Dim objcount As Integer
objcount = 0

fld = FolderSelect()
If Len(fld) < 3 Then Exit Function

Set fs = CreateObject("Scripting.FileSystemObject")
Set f = fs.GetFolder(fld)
Set fc = f.Files

For Each f1 In fc
If f1 Like "*.*xls*" Then
Set wb = Workbooks.Open(Filename:=fld & "\" & f1.Name)

wb.Activate
For Each i In ActiveSheet.Shapes
If i.Type = msoLinkedOLEObject Then
Debug.Print i.Name
objcount = objcount + 1
End If
Next
If objcount > 0 Then MsgBox "Workbook " & wb.Name & " has " & objcount & " msoLinkedOLEObject."
wb.Close
Set wb = Nothing

End If
Next
End Function


Public Function FolderSelect() As String
Dim fd As FileDialog
Set fd = Application.FileDialog(msoFileDialogFolderPicker)
Dim vrtSelectedItem As Variant
With fd
.AllowMultiSelect = False
If .Show = -1 Then
FolderSelect = .SelectedItems(1)
Else
End If
End With
Set fd = Nothing
End Function
 
Upvote 0
Pedie,

Thanks for your solution, it works fine. Now I have to add a logging part so that after checking the files a get an overview of the files wich have embedded objects inside.

Best Regards,

Marc
 
Upvote 0
try this code.
it will list files names and objects count.


the code is not Tested but should work :)
Code:
Code:
[FONT=courier new]Option Explicit
Public Function ShowFolderList()[/FONT]
[FONT=courier new]Dim wb As Workbook
Dim i As Shape
Dim fld As String
Dim fs, f, f1, fc
Dim objcount As Integer
Dim wb1 As Workbook[/FONT]
[FONT=courier new]
Set wb1 = Workbooks.Add
wb1.Sheets(1).Range("A1").Value = "Workbook Names"
wb1.Sheets(1).Range("B1").Value = "msoLinkedOLEObject Count"
Cells.EntireColumn.AutoFit[/FONT]
[FONT=courier new]objcount = 0[/FONT]
[FONT=courier new]fld = FolderSelect()
If Len(fld) < 3 Then Exit Function
Set fs = CreateObject("Scripting.FileSystemObject")
Set f = fs.GetFolder(fld)
Set fc = f.Files[/FONT]
[FONT=courier new]   For Each f1 In fc
        If f1 Like "*.*xls*" Then
        Set wb = Workbooks.Open(Filename:=fld & "\" & f1.Name)
        
            wb.Activate
            For Each i In ActiveSheet.Shapes
                If i.Type = msoLinkedOLEObject Then
                    objcount = objcount + 1
                End If
            Next
            
                If objcount > 0 Then
                    wb1.Sheets(1).Range("A" & Rows.Count).End(xlUp).Offset(1, 0).Value = wb.Name
                    wb1.Sheets(1).Range("A" & Rows.Count).End(xlUp).Offset(0, 1).Value = objcount
                End If
                
            wb.Close
            Set wb = Nothing
        End If
    Next
wb1.activate
msgbox "Completed!"

End Function
Public Function FolderSelect() As String
Dim fd As FileDialog
Set fd = Application.FileDialog(msoFileDialogFolderPicker)
Dim vrtSelectedItem As Variant
With fd
.AllowMultiSelect = False
If .Show = -1 Then
FolderSelect = .SelectedItems(1)
Else
End If
End With
Set fd = Nothing
End Function[/FONT]
 
Upvote 0

Forum statistics

Threads
1,214,918
Messages
6,122,255
Members
449,075
Latest member
staticfluids

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