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: Testing for an Empty Worksheet.

Testing for an Empty Worksheet

Written by Allen Wyatt (last updated October 9, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


Michael has a macro that prints a number of worksheets. Occasionally one or two of the worksheets to be printed may contain no data. He is looking for a technique to test whether a worksheet contains data, and then only print those worksheets.

There are several ways you can go about testing for an empty worksheet. Of course, it depends on what you really mean by "empty," at least to a degree. For instance, if a worksheet has absolutely nothing in it—nothing in any cell of the worksheet—we could consider it empty. However, you might have a worksheet that contains some column headings that you added, but nothing except those headings. While Excel would consider the worksheet not empty, you might consider it empty for printing purposes.

Perhaps the easiest way to check if a worksheet is empty is to use the UsedRange object to deterrnine what is in the worksheet:

With ActiveSheet.UsedRange
    IsSheetEmpty = .Rows.Count = 1 And _
      .Columns.Count = 1 And _
      .Cells(1,1) = ""
End With

Note that the UsedRange object consists of, well, the range of used cells within a worksheet. Thus, if the count of rows in this range is 1 and the count of columns in this range is 1, and there is nothing in the first cell of the UsedRange object, then the worksheet is probably empty.

Depending on the characteristics of your data, you may be able to shorten the code even more:

With ActiveSheet.UsedRange
    IsSheetEmpty = .Count = 1 And .Cells(1,1) = ""
End With

In this version you are simply checking to see if the count of cells in the UsedRange object is 1 and if that particular cell is empty.

If you have a header row (or two) in your worksheet, then you can adjust this technique to however may rows and columns you have in those headers. For instance, if you have headers in the range A1:F4, then you might adjust the technique in this manner:

IsSheetEmpty = ActiveSheet.UsedRange.Rows.Count=4 _
  AND ActiveSheet.UsedRange.Columns.Count=6

You don't need to check the contents of A1 in this instance because you already know that it (and several other cells) contain information—your headers. You just want to ignore everything in those headers to determine if there is additional information in the worksheet.

If the worksheet is completely empty (no header information that you've added), you can use the CountA worksheet function to analyze the cells in the worksheet. If the result of the function is greater than zero, then the worksheet is not empty. For example, let's say that the worksheet you want to analyze is specified by the object sht. You can use this technique in this manner:

IsSheetEmpty = Application.WorksheetFunction.CountA(sht.Cells) = 0

Of course, it is possible for a worksheet to contain items other than information in cells. If you suspect you will have these types of objects in a worksheet (things like AutoShapes, graphics, or embedded charts), then your testing for "emptiness" will need to be more complete. Each of these items are contained within collections that are accessible in VBA, and you can check the Count property for each collection to see if it is zero or not.

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 (9637) 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: Testing for an Empty Worksheet.

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

Suppressing ASK Fields When Printing

Do you like using ASK Fields in your documents to get information from the user but don't want Word to update the fields ...

Discover More

Formatting Fractions

Need to have a great looking fraction in a document? It's relatively easy to do if you apply the formatting techniques ...

Discover More

Preparing Data for Import into Access

When importing Excel information into Access, you need to be concerned with the condition of the data. Here's how to make ...

Discover More

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!

More ExcelTips (ribbon)

Sorting Worksheets According to Region

Sorting worksheet tabs can be done by using a macro. This tip provides a macro that accomplishes this task, but it also ...

Discover More

Dynamic Worksheet Tab Names

Need a worksheet's name to change based on the contents of a cell? You'll need to rely on a macro to do the changing, but ...

Discover More

Moving from Sheet to Sheet

Need to move quickly through the worksheets in a workbook? Learn the keyboard shortcuts and you can make short work 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 more than 7?

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.