Macro to Count the Number of Procedures on a Module Sheet (128374)



The information in this article applies to:

  • Microsoft Excel for Windows 95 7.0a
  • Microsoft Excel for Windows 5.0c
  • Microsoft Excel for Windows NT 5.0
  • Microsoft Excel for the Macintosh 5.0a

This article was previously published under Q128374

SUMMARY

In Microsoft Excel, you can count the number of procedures on a module sheet by determining the number of times the word "Sub" appears as the first three characters on a line. Similarly, you can display each of the macro names that are on a module sheet.

One way to count the number of procedures on a module sheet is to create a macro that saves the module sheet as a text file and then reads each line of the text file to count the occurrences of the word "Sub." To return the names of the macros on the module sheet, you can create a similar macro that saves the module sheet as a text file and then displays the text that follows each occurrence of the word "Sub" in the text file. This article provides sample macros that demonstrate how each of these procedures can be done.

Sample Visual Basic, Applications Edition, Macro Code

NOTE: Because of the design of the Visual Basic Editor in Microsoft Excel 97 for Windows and Microsoft Excel 98 Macintosh Edition, the following code will not work in these versions of Microsoft Excel. More information will be added to this article as it becomes available.

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.

Macro to Count Number of Procedures on a Module Sheet

The following macro saves a module sheet to a text file, opens the text file, counts the number of lines that start with "Sub" and then displays this as the number of macros in the module:
   Sub CountSubs()

       Dim Count As Integer, Filenum As Integer, textline As String

       ' Initialize the count of procedures to zero.
       Count = 0

       ' Save Module1 as a text file called TEMPFILE.TXT.
       Modules("Module1").Select
       ActiveWorkbook.SaveAs "TEMPFILE.TXT", xlText

       ' Retrieve the next available file number as FileNum and then open
       ' the text file with the file number.
       Filenum = FreeFile()
       Open "TEMPFILE.TXT" For Input As #Filenum
       On Error GoTo CloseFile

       ' Read each line of the text file until the end of the file is
       ' reached. If the first 3 characters of the line of text is equal to
       ' "Sub" after trimming excesses spaces, then increment count.

       Do While Not (EOF(Filenum))
           Line Input #Filenum, TextLine
           If Left(LTrim(TextLine), 3) = "Sub" Then Count = Count + 1
       Loop

       ' Close the file.
       Close #Filenum

       ' Display the count for the number of subs in the module sheet
       ' and Exit this procedure.

       MsgBox "There are " & Count & " Subs in Module1 of the " & _
           "active workbook."
       Exit Sub

   CloseFile:

       ' Close the file and display a message that an error occurred.
       Close Filenum
       MsgBox "An error occurred"

   End Sub
				
NOTE: If you want the macro to account for private, public, and static Sub statements as well, replace the following line of the macro:
   If Left(LTrim(TextLine), 3) = "Sub" Then Count = Count + 1
				
with this code:
   If Left(LTrim(TextLine), 3) = "Sub" Then Count = Count + 1
   If Left(LTrim(TextLine), 11) = "Private Sub" then Count = Count + 1
   If Left(LTrim(TextLine), 10) = "Public Sub" Then Count = Count + 1
   If Left(LTrim(TextLine), 10) = "Static Sub" Then Count = Count + 1
				

Macro to Display Macro Names Contained on a Module Sheet

The following macro saves a module sheet to a text file, opens the text file, searches for lines that start with "Sub" and then strips out the macro name to display it:
   Sub DisplaySubs()

       Dim Filenum As Integer, textline As String
       Dim leftparen As Integer, macroname As String

       ' Save Module1 as a text file called TEMPFILE.TXT.
       Modules("Module1").Select
       ActiveWorkbook.SaveAs "TEMPFILE.TXT", xlText

       ' Retrieve the next available file number as FileNum and then open
       ' the text file with the file number.
       Filenum = FreeFile()
       Open "TEMPFILE.TXT" For Input As #Filenum
       On Error GoTo CloseFile

       ' Read each line of the text file until the end of the file is
       ' reached. If the first 3 characters of the line of text is equal to
       ' "Sub" after trimming excess spaces, get the macro name and display
       ' it.

       Do While Not (EOF(Filenum))
           Line Input #Filenum, TextLine
           If Left(LTrim(TextLine), 3) = "Sub" Then
               LeftParen = InStr(1, TextLine, "(")
               macroname = Mid(Left(TextLine, LeftParen - 1), 5)
               MsgBox macroname
           End If
       Loop

       ' Close the file.
       Close #Filenum

       Exit Sub

   CloseFile:

       ' Close the file and display a message that an error occurred.
       Close Filenum
       MsgBox "An error occurred"

   End Sub
				

Modification Type:MinorLast Reviewed:10/11/2006
Keywords:kbcode kbhowto kbProgramming KB128374