Results 1 to 7 of 7

Thread: Page X of Y

  1. #1
    Bronze Lounger
    Join Date
    Jan 2001
    Posts
    1,418
    Thanks
    1
    Thanked 0 Times in 0 Posts

    Page X of Y

    I have a worksheet that is made up of 5 pages. In the cell located at Row 3, Column M, Page 1 I currently have the text "Page 1 of ___", and have Excel repeating Rows 1-5 of Page 1 on each subsequent page. What I would like is to have Excel insert Page 1 of the total number of pages on page 1 (since the number may change, page 2 of the same, etc., throughout the whole of the worksheet, instead of my doing it manually.

    Any ideas?

    Thanks in advance. on page 1 of the worksheet,

  2. #2
    Lounger akjudge's Avatar
    Join Date
    Jan 2014
    Posts
    41
    Thanks
    1
    Thanked 8 Times in 7 Posts
    I do what I think you want by doing it in a Footer as opposed to in the worksheet itself.
    Go to Print Preview --> Page Setup --> Click on Custom Footer then add the following to one of the boxes:

    Page &[Page] of &[Pages] Pages

    Click OK... I think this is what you are looking for, if I understand your question. If not, just wait until one of the real Excel experts here can help you.

    Jim

  3. #3
    Bronze Lounger
    Join Date
    Jan 2001
    Posts
    1,418
    Thanks
    1
    Thanked 0 Times in 0 Posts
    Thanks Jim. Yes, I know how to do it via the Header/Footer route, but would prefer my way, if at all possible!

  4. #4
    WS Lounge VIP sdckapr's Avatar
    Join Date
    Jul 2002
    Location
    Pittsburgh, Pennsylvania, USA
    Posts
    11,225
    Thanks
    14
    Thanked 342 Times in 335 Posts
    You will need 2 things a named formula for the calculating the total pages and user-defined-function for determing what page a cell is on.

    Named formula (directions for XL2010, adapt as needed):
    Formulas - Define name [In earlier versions I recall insert - name -define]
    Name: TotalPages
    Refers to: =GET.DOCUMENTS(50)
    [ok]

    For the UDF, Add this function to a module:
    Code:
    Option Explicit
    Public Function GetPageNumber(rCell As Range) As String
      Dim iVPC As Integer, iHPC As Integer
      Dim VerPB As VPageBreak, HorPB As HPageBreak
      Dim iNumPage As Integer
      Application.Volatile
      If ActiveSheet.PageSetup.Order = xlDownThenOver Then
        iHPC = ActiveSheet.HPageBreaks.Count + 1
        iVPC = 1
      Else
        iVPC = ActiveSheet.VPageBreaks.Count + 1
        iHPC = 1
      End If
      iNumPage = 1
      For Each VerPB In ActiveSheet.VPageBreaks
        If VerPB.Location.Column > rCell.Column Then Exit For
        iNumPage = iNumPage + iHPC
      Next VerPB
      For Each HorPB In ActiveSheet.HPageBreaks
        If HorPB.Location.Row > rCell.Row Then Exit For
        iNumPage = iNumPage + iVPC
      Next HorPB
      GetPageNumber = iNumPage
    End Function
    Then in a cell (eg M3) enter the following formula:
    ="Page " & GetPageNumber(M3) & " of "&TotalPages

    This will display something like "Page 1 of 5"

    Copy this cell to any cells you want this to be displayed (and the formula will be adjusted). [The cell reference does NOT have the cell the formula is in, it can be any cell on the page of interest.]

    Steve

  5. #5
    WS Lounge VIP sdckapr's Avatar
    Join Date
    Jul 2002
    Location
    Pittsburgh, Pennsylvania, USA
    Posts
    11,225
    Thanks
    14
    Thanked 342 Times in 335 Posts
    Cross-posted (see note about cross-posting at http://www.excelguru.ca/content.php?184) on the page http://eileenslounge.com/viewtopic.php?f=27&t=15902

    Steve

  6. #6
    Gold Lounger Maudibe's Avatar
    Join Date
    Aug 2010
    Location
    Pa, USA
    Posts
    2,631
    Thanks
    115
    Thanked 645 Times in 589 Posts
    jlkirk,

    If I understand you correctly, you would like to insert the page numbers on a sheet in the form of "Page X of Y" on the 3rd line and 13th column of each page and the number of pages may vary.

    This code will accommodate any number of pages assuming that they are all in vertical alignment as well as any custom page breaks. It finds the location of the page break then places the page number 2 rows below it (3 rows down). Place in a standard module and change the worksheet number (Worksheets(1), 2 instances) to the sheet number you would like to format. If this is what you are looking for, the code can easily be adapted to format all the sheets in the workbook. You can run this from Macros on the developer tab or, depending on your version, add it as an icon to the Quick Access toolbar.

    I think a UDF defeats the purpose. Entering the formula in a cell on each page constitutes as much effort as manually entering "Page X of Y" or maybe I am missing something.

    HTH,
    Maud

    Code:
    Public Sub NumPages()
    Dim rng As Range
    '------------------------------------------
    'GET NUMBER OF PAGE BREAKS AND SET UP FIRST PGE NUMBER
    num = Worksheets(1).HPageBreaks.Count
    Cells(3, 13) = "Page 1 of " & num + 1
    '------------------------------------------
    'GET SUBSEQUENT PAGE BREAKS AND SET UP SUBSEQUENT PAGE NUMBERS
    For I = 1 To num
        Set rng = Worksheets(1).HPageBreaks(I).Location
        Cells(rng.Row + 2, 13) = "Page " & I + 1 & " of " & num + 1
    Next I
    End Sub
    Last edited by Maudibe; 2014-03-20 at 21:13.

  7. #7
    Bronze Lounger
    Join Date
    Jan 2001
    Posts
    1,418
    Thanks
    1
    Thanked 0 Times in 0 Posts
    Thanks to all. Sorry, Steve, I was under the gun on a deadline...

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •