Microsoft KB Archive/108350

From BetaArchive Wiki
Knowledge Base


Distinguishing Sheet Types with Visual Basic Macro

Article ID: 108350

Article Last Modified on 10/10/2006



APPLIES TO

  • Microsoft Excel 97 Standard Edition
  • Microsoft Excel 98 for Macintosh



This article was previously published under Q108350

SUMMARY

You can use the Microsoft Visual Basic for Applications TypeName function to return each type of sheet available in Microsoft Excel. Because the Worksheet type can apply to worksheets, MS Excel 4.0 Macro sheets, or MS Excel 4.0 International Macro sheets, you must use the Type property along with the TypeName function to return the specific type of worksheet.

The sample macro (Sub procedure) in the "More Information" section of this article displays the appropriate sheet name for each sheet:

Chart
DialogSheet
Module (except in Microsoft Excel 97 and Microsoft Excel 98)
MS Excel 4.0 Macro Sheet
MS Excel 4.0 International Macro Sheet
Worksheet


MORE INFORMATION

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. The following Visual Basic code examples assume that you have a workbook that contains one worksheet, one MS Excel 4.0 Macro sheet, one chart sheet, one dialog sheet, and one Visual Basic module, in that order. The code example is located in the Visual Basic module.

To run the macro, position the insertion point in the line that reads "Sub Sheet_Type()" and click Start on the Run menu.

   Option Explicit

   Sub Sheet_Type()
       ' Dimension variables.
       Dim X As Variant
       ' Iterate through the loop once for each sheet in the workbook.
       For Each X In ActiveWorkbook.Sheets

           ' If the sheet's TypeName is "Worksheet", then...
           If TypeName(X) = "Worksheet" Then
               ' Check for each Type (xlWorksheet, xlExcel4MacroSheet,
               ' xlExcel4IntlMacroSheet) and display the appropriate
               ' message box.
               If X.Type = xlWorksheet Then
                   MsgBox "Worksheet"
               ElseIf X.Type = xlExcel4MacroSheet Then
                   MsgBox "MS Excel 4.0 Macro Sheet"
               ElseIf X.Type = xlExcel4IntlMacroSheet Then
                   MsgBox "MS Excel 4.0 International Macro Sheet"
               End If

           ' Otherwise, display a message box with the appropriate
           ' TypeName.
           Else
               MsgBox TypeName(X)         ' Show sheet type in message box.
           End If
       Next                               ' Repeat the loop until finished.
   End Sub
                

When you run the Sheet_Type subroutine, the messages you receive are:

Worksheet, MS Excel 4.0 Macro Sheet, Chart, DialogSheet, Module


NOTE: In Microsoft Excel 97 and Microsoft Excel 98, you do not receive a message box for the module. This occurs because of the design of the Visual

Basic Editor in these versions of Microsoft Excel.


Additional query words: 5.00c 7.00a XL98 XL97 XL7 XL5 XL

Keywords: kbdtacode kbhowto kbprogramming KB108350