Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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: Page Numbers in VBA.
Written by Allen Wyatt (last updated July 18, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Steve is looking for a way to determine, in a VBA macro, the number of pages that a worksheet will have, when printed, and the page number on which a particular cell will print. This task is not quite as easy as one would hope, but it can be done.
It seems that the best way to handle this is to use an outmoded (but still available) Excel 4 function to determine the number of total printed pages in a worksheet. Then you can use the HPageBreaks and VPageBreaks collections to figure out where the cell falls in the matrix of pages that will be printed. The following is an example of a macro that utilizes these items:
Sub PageInfo() Dim iPages As Integer Dim iCol As Integer Dim iCols As Integer Dim lRows As Long Dim lRow As Long Dim x As Long Dim y As Long Dim iPage As Integer iPages = ExecuteExcel4Macro("Get.Document(50)") With ActiveSheet y = ActiveCell.Column iCols = .VPageBreaks.Count x = 0 Do x = x + 1 Loop Until x = iCols _ Or y < .VPageBreaks(x).Location.Column iCol = x If y >= .VPageBreaks(x).Location.Column Then iCol = iCol + 1 End If y = ActiveCell.Row lRows = .HPageBreaks.Count x = 0 Do x = x + 1 Loop Until x = lRows _ Or y < .HPageBreaks(x).Location.Row lRow = x If y >= .HPageBreaks(x).Location.Row Then lRow = lRow + 1 End If If .PageSetup.Order = xlDownThenOver Then iPage = (iCol - 1) * (lRows + 1) + lRow Else iPage = (lRow - 1) * (iCols + 1) + iCol End If End With MsgBox "Cell " & ActiveCell.Address & _ " is on " & vbCrLf & "Page " & _ iPage & " of " & iPages & " pages" End Sub
One thing that you should keep in mind with this macro is that the HPageBreaks and VPageBreaks collections are only considered accurate if you are viewing the worksheet in Page Break Preview (View | Page Break Preview). Thus, you'll want to make sure that you are in that mode before selecting a cell and running the macro.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11581) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Page Numbers in VBA.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
Need to know how to generate a full month name based on a date? It's easy to do, as discussed in this tip.
Discover MoreThe personal macro workbook is a great place to save your macros that you want to use with any workbook. The personal ...
Discover MoreWhen you open multiple workbooks, the way in which Excel sizes them is not the best for your needs. This tip looks at a ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments