For Pro's - Link, Macro in workbooks folders

paludgnp

New Member
Joined
Feb 18, 2002
Messages
24
Hello,

This one is pretty difficult.
I have a folder with many many workbooks, and I would like to determine automatically whether these workbook has some linked info or include macros.
In other terms, for people who prefer code as words:

for each WORKBOOK in FOLDER
if IsLink(WORKBOOK)=true then Msgbox "WORKBOOK" & WORKBOOK " has link"
if ISMacro(WORKBOOK)=true then Msgbox "WORKBOOK" & WORKBOOK " has Macro" next WORKBOOK

Good luck,
Pierre
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
It's not that difficult...

For the second function to work you must set a reference to "Microsoft Visual Basic For Applications Extensibility"

Here are the functions:

Code:
Option Explicit

Function HasLinks(WbName As String) As Boolean
Dim W As Workbook
Dim a
On Error GoTo Exiting
Set W = Workbooks(WbName)
On Error GoTo 0
a = W.LinkSources
HasLinks = Not IsEmpty(a)
Exiting:
End Function

Function HasMacros(WbName As String) As Boolean
Dim W As Workbook
Dim WM As VBComponent
On Error GoTo Exiting
Set W = Workbooks(WbName)
For Each WM In W.VBProject.VBComponents
    If WM.CodeModule.CountOfLines > 2 Then HasMacros = True: Exit Function
Next WM
Exiting:
End Function

The .CountOfLines > 2 is that way because there may be an "Option Explicit" there, WHICH doesn't qualify as macro, but makes 2 lines.

You can use it like

?HasLinks(ThisWorkbook.Name)

or

?HasMacros("Testing.xls")

or in Excel

=HasMacros("OtherTest.xls")

The workbook MUST BE OPEN.
 
Upvote 0

Forum statistics

Threads
1,214,641
Messages
6,120,695
Members
448,979
Latest member
DET4492

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