Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Generating a List of Macros.
Written by Allen Wyatt (last updated January 31, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Andrew has a workbook that has a good number of macros in it. He would like to generate a list of all the macros it contains, so he wonders if there is a way to accomplish the task.
There is no intrinsic way within Excel to create a list of macros. You can, however, create a macro that will list your macros. (Sort of sounds redundant, doesn't it?)
As an example, consider the following macro, which steps through all the projects in your workbook to garner all the macro names and place them in a worksheet:
Sub ListMacros() Dim VBComp As VBComponent Dim wsTarget As Worksheet Dim StartLine As Long Dim iRow As Integer Application.ScreenUpdating = False Set wsTarget = Worksheets.Add wsTarget.Range("A1") = "Macro" wsTarget.Range("A1").Font.Bold = True With wsTarget.Range("A1").Borders(xlEdgeBottom) .LineStyle = xlContinuous .ColorIndex = 0 .TintAndShade = 0 .Weight = xlThin End With iRow = 2 For Each VBComp In ThisWorkbook.VBProject.VBComponents With VBComp.CodeModule StartLine = .CountOfDeclarationLines + 1 Do Until StartLine >= .CountOfLines wsTarget.Cells(iRow, 1) = _ .ProcOfLine(StartLine, vbext_pk_Proc) iRow = iRow + 1 StartLine = StartLine + _ .ProcCountLines(.ProcOfLine(StartLine, _ vbext_pk_Proc), vbext_pk_Proc) Loop End With Next VBComp wsTarget.Range("A1").EntireColumn.AutoFit Application.ScreenUpdating = True End Sub
In order to use this macro, you must make sure you have the Microsoft VBA extensibility reference set. To do this, follow these steps:
Figure 1. The References dialog box.
You'll also need to make a quick change in your Trust Center settings. Follow these steps:
Figure 2. The Trust Center dialog box.
When you run the macro, it adds a new worksheet to your workbook, and then lists the names of all the macros in all the modules in the workbook.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (5225) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Generating a List of Macros.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
On your system you may have workbooks that contain macros you know are safe to use. Microsoft provides two things you can ...
Discover MoreDo you often need to know the difference between two values in your worksheet? This tip shares a quick little macro that ...
Discover MoreWhen you add a new worksheet to a workbook, Excel gives it a default name that consists of "Sheet" followed by a number. ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-05-09 12:02:48
J. Woolley
Re. the Tip's ListMacros procedure, if you substitute procKind for each instance of vbext_pk_Proc as recommended in my previous comment and change the declaration of VBComp as follows
Dim VBComp As Object 'not VBComponent
then you don't need to reference the Microsoft Visual Basic for Applications Extensibility library.
Also, you should change ThisWorkbook to ActiveWorkbook as suggested by Peter.
See http://www.cpearson.com/excel/vbe.aspx
2022-05-08 09:42:48
J. Woolley
@Kerry and Peter
To accommodate VBA procedures that are neither Sub nor Function, add the following statement to the Tip's ListMacros:
Dim procKind as Long
Then substitute procKind for each instance of vbext_pk_Proc (there are 3 instances).
2022-05-07 10:41:46
J. Woolley
My Excel Toolbox includes the following dynamic array function:
=ListProcs([SkipHeader])
This function returns the following 6 columns for each VBA procedure in the workbook:
Component (name), Type (module or user form), Procedure (name), Type (Sub or Function), Scope (Public or Private), Declaration. An example Declaration follows:
Public Function ListProcs(Optional SkipHeader As Boolean = False) As Variant()
In older versions of Excel you can use ListProcs with the SpillArray function like this:
=SpillArray(ListProcs([SkipHeader])
See https://sites.google.com/view/MyExcelToolbox/
2022-05-06 04:18:18
Kerry
Hi Allen,
I 've used this code in 2 workbooks, but it only works on 1. The excel settings are obviously identical.including the references in tools specific to the active workbook.
Only one workbook open at a time.
the code stops at
StartLine = StartLine + .ProcCountLines(.ProcOfLine(StartLine, _
vbext_pk_Proc), vbext_pk_Proc)
error is "sub or function not defined"
when I check the worksheet that contains the list, it as stopped at code in a form. I don't know if that is relevant or not.
this function is SO handy. what could be the problem. it works fine in another workbook
2018-01-28 12:06:14
Walter
Peter
Thank you very, very much for going the extra mile and making this a very, very useful macro.
I was just about to take your previous suggestion of extending the macro when you are latest post appeared. I am sure you saved me many hours of time. I knew zilch about VBComponents, but am a little bit more knowledgeable about them now.
I'm sure there will be others like me who spend a lot of time trying to find a macro and can't remember its name or where it is. A table of contents for your macro workbook is a very useful feature that has been missing for years. Thanks to Allen for introducing this, and to you, for your very useful extension.
2018-01-27 10:56:05
Peter Atherton
This is a really useful macro - Kudos to Allen!!
I copied it into my personal workbook and found it needed a bit of revision to work on the active workbook. The following is the revised code if you want to place it in the PERSONAL.XLSB workbook.
Option Explicit
Sub ListMacros()
Dim VBComp As VBComponent
Dim wsTarget As Worksheet, wks As Worksheet
Dim wkb As Workbook
Dim StartLine As Long
Dim iRow As Integer
With Application
.ScreenUpdating = False
.DisplayAlerts = False
End With
Set wkb = ActiveWorkbook
With wkb
For Each wks In ActiveWorkbook.Sheets
If wks.Name = "ListMacros" Then
wks.Delete
End If
Next
Set wsTarget = Worksheets.Add
wsTarget.Name = "ListMacros"
wsTarget.Range("A1") = "Modules' Name"
wsTarget.Range("b1") = "Macros' Name"
wsTarget.Range("A1:B1").Font.Bold = True
With wsTarget.Range("A1:b1").Borders(xlEdgeBottom)
.LineStyle = xlContinuous
End With
iRow = 2
For Each VBComp In wkb.VBProject.VBComponents
With VBComp.CodeModule
StartLine = .CountOfDeclarationLines + 1
Do Until StartLine >= .CountOfLines
wsTarget.Cells(iRow, 1) = VBComp.CodeModule.Name
wsTarget.Cells(iRow, 2) = _
.ProcOfLine(StartLine, vbext_pk_Proc)
iRow = iRow + 1
StartLine = StartLine + _
.ProcCountLines(.ProcOfLine(StartLine, _
vbext_pk_Proc), vbext_pk_Proc)
Loop
End With
Next VBComp
wsTarget.Range("A1:b1").EntireColumn.AutoFit
With Application
.ScreenUpdating = True
.DisplayAlerts = True
End With
End With
End Sub
2018-01-21 11:00:49
Peter Atherton
Walter
add this line above the macro name (after the do loop
wsTarget.Cells(iRow, 1) = VBComp.CodeModule.Name
and change the code name column to 2
2018-01-20 16:28:18
Walter
Good macro as far as it goes. It would be very much more useful to me if the macro also placed the module name/number of the extracted macro name in column B.
Is this left as an exercise for the student?
Or, will there be a part two next week?
Or, if it is easy enough, could someone please extend the macro so that we can also quickly located in its module?
2018-01-20 16:19:26
Walter
@Stefan
I had the same problem. I fixed it by making sure the Microsoft Visual Basic for Applications Extensibility check box is selected in the VBAProject where I placed the macro code.
2018-01-20 11:31:59
In the January 20th Excel Tips was a "Generating a List of Macros".
I'm running Office 365 and have LOTS of Macros in an Excel Workbook with 12 Worksheets.and at least 66 Macros.
I have 'discovered' the ability to list the Macros in VBA which can be "stepped into" or "edited".
This is quite nice because I have nearly 100 printed pages of VBA. When trying to find a specific Macro:
------
With VBA on the monitor...
Across the top line you will find "Tools" -- click on it.
In the drop-down list you will find "Macros" -- click on it. You will find a list of all Macros in the Workbook.
Within the listing you can 'Run", 'Step Into', or 'Edit' the macro. (Using this is quite useful since you don't have to search out the macro.)
------
[ I can't validate that ALL macros are listed; it would simply take more time to compare lists than it is worth. ]
I wish there was a similar facility for listing 'controls' as there likely over 250 'buttons' within the Workbook.
2018-01-20 11:17:14
stefan
i get the error, "User-defined type not defined" referring to the statement: Dim VBComp As VBComponent
i've done everything else!
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments