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: Detecting Types of Sheets in VBA.

Detecting Types of Sheets in VBA

Written by Allen Wyatt (last updated May 16, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


If you are writing macros that process different worksheets in a workbook, you may have a need to figure out what type of worksheets there are in the workbook, before doing any processing. This can be especially critical because some VBA commands only work on certain types of worksheets.

Before you can figure out what types of worksheets are in a workbook, it is helpful to know how Excel internally stores some of the objects that make up the workbook. Excel maintains both a Worksheets collection and a Charts collection. The Worksheets collection is made up of worksheet objects, and the Charts collection is made up of chart sheet objects. Chart sheet objects are those charts that take up an entire worksheet; it does not include those that are objects embedded within a worksheet.

Interestingly enough, worksheet and chart sheet objects are also members of the Sheets collection. So, if you want to process a workbook in the order that the sheets occur, it is easiest to do so by stepping through the Sheets collection. When you do so, you can examine the Type property of individual objects within the collection to determine what type of object it is. Excel defines two types of objects that can belong to the Sheets collection:

  • xlWorksheet. This is a regular worksheet.
  • xlChart. This is a chart.

The following two types of objects are still supported by Microsoft Excel, but Microsoft recommends that you migrate them to the latest version of Microsoft VBA. (See the webpage listed below for more information on working with Excel 4.0 macros.):

  • xlExcel4MacroSheet. This is a macro sheet, as used in Excel 4.0.
  • xlExcel4IntlMacroSheet. This is an international macro sheet, as used in Excel 4.0.
https://support.office.com/en-us/article/Working-with-Excel-4-0-macros-BA8924D4-E157-4BB2-8D76-2C07FF02E0B8

You might be tempted to think that looking at the list of sheet types is enough. Interestingly, however, Excel doesn't always return what you would expect for the Type property. Instead, if you examine the Type property for a chart, it returns a value equal to xlExcel4MacroSheet. This can cause problems for any macro.

The way around this, then, is to compare the name of each item in the Sheets collection against those in the Charts collection. If the name is in both collections, then it is safe to assume that the sheet is a chart. If it is not in both, then you can analyze further to see if the worksheet is one of the other types. The following macro, SheetType, follows exactly this process:

Sub SheetType()
    Dim iCount As Integer
    Dim iType As Integer
    Dim sTemp As String
    Dim oChart As Chart
    Dim bFound As Boolean

    sTemp = ""
    For iCount = 1 To Sheets.Count
        iType = Sheets(iCount).Type
        sTemp = sTemp & Sheets(iCount).Name & " is a"

        bFound = False
        For Each oChart In Charts
            If oChart.Name = Sheets(iCount).Name Then
                bFound = True
            End If
        Next oChart

        If bFound Then
            sTemp = sTemp & " chart sheet."
        Else
            Select Case iType
                Case xlWorksheet
                    sTemp = sTemp & " worksheet."
                Case xlChart
                    sTemp = sTemp & " chart sheet."
                Case xlExcel4MacroSheet
                    sTemp = sTemp & "n Excel 4 macro sheet."
                Case xlExcel4IntlMacroSheet
                    sTemp = sTemp & "n Excel 4 international macro sheet"
                Case Else
                    sTemp = sTemp & "n unknown type of sheet."
            End Select
        End If
        sTemp = sTemp & vbCrLf
    Next iCount
    MsgBox sTemp
End Sub

When you run the macro, you see a single message box that shows the name of each sheet in your workbook, along with what type of sheet it is.

Finally, remember that this code tells you what types of sheets are in a workbook; it doesn't tell you what type of workbook they are contained in. (In other words, the macro doesn't care what version of Excel you are working in.)

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10483) 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: Detecting Types of Sheets in VBA.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Comparing Documents Top and Bottom

Word has a feature that allows you to compare two documents side-by-side. What if you actually want to compare the ...

Discover More

Flashing Cells

Want to draw attention to some information in a particular cell? Make the cell flash, on and off. Here's how you can ...

Discover More

Understanding Operators

At the heart of working with Excel is the process of creating formulas that calculate results based on information within ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Freezing Top Rows and Bottom Rows

Freezing the top rows in a worksheet so that they are always visible is easy to do. Freezing the bottom rows is not so ...

Discover More

Referencing Worksheet Tabs

Ever want to use the name of a worksheet tab within a cell? Here's how you can access that information using the CELL ...

Discover More

Jumping to a Specific Worksheet

Want to make fast work of moving from one worksheet to another? Here's how to do the task when you have a lot of ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is two less than 9?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.