Written by Allen Wyatt (last updated August 12, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003
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 embeded 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 four types of objects that can belong to the Sheets collection:
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, than 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.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2538) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Detecting Types of Sheets in VBA.
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!
Radio buttons are great for some data collection purposes. They may not be that great for some purposes, however, for the ...
Discover MoreYou can protect various parts of your worksheets by using the tools built into Excel. One thing you can protect is the ...
Discover MoreExcel allows the user to determine how many default worksheets are in a new workbook.
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2015-09-14 09:16:09
You can use the Typename function in combination with the Type property to determine what kind of sheet you are looking at. Only one kind of chart, the Column chart, returns the same Type value (3) as a macro sheet. Here is a table showing the TypeName in column 2 and the Type value in column 3:
Column Chart Chart 3
Bar Chart Chart 2
Line Chart Chart 4
Pie Chart Chart 5
Area Chart Chart 1
Doughnut Chart Chart -4120
Radar Chart Chart -4151
Surface Chart Chart -4103
XY Chart Chart -4169
Bubble Chart Chart -4169
Sheet1 Worksheet -4167
Macro1 Worksheet 3
Int'l Macro2 Worksheet 4
The only ambiguity here is that the XY Chart and the Bubble chart return the same Type number.
2014-05-19 08:42:51
Nice macro.
I modify the code, just to adjust it to my context.
Thanks for your work.
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2023 Sharon Parq Associates, Inc.
Comments