Consulting

Results 1 to 4 of 4

Thread: Solved: Setting Dynamic Print Range

  1. #1

    Solved: Setting Dynamic Print Range

    Hi,

    I need some help in setting up a macro that will set up the print area of my document which will be updated frequently and need to ensure that it will pick up the last row of Column A and the number of Columns will remain the same (Column J).

    Thanks

    BT

  2. #2
    VBAX Regular JONvdHeyden's Avatar
    Joined
    Mar 2009
    Location
    Hampshire, UK
    Posts
    75
    Location
    For just the one sheet? What is in column A, numbers or text?

    You can create a dynamic named range. The range name may already exist called Print_Area.

    If column A house numbers then change the name to refer to:
    =!$A$1:INDEX(!$J:$J,MATCH(9.99999999999999E+307,!$A:$A))

    If column A house text then change the name to refer to:
    =!$A$1:INDEX(!$J:$J,MATCH(REPT("Z",255),!$A:$A))
    Regards,
    Jon von der Heyden (Excel 2003, OS XP Pro)

  3. #3
    Hi JONvdHeyden,

    Thanks very much for your help.

    That name range works a treat when fired up using a macro.

    Cheers mate.

    BT

  4. #4
    Moderator VBAX Wizard lucas's Avatar
    Joined
    Jun 2004
    Location
    Tulsa, Oklahoma
    Posts
    7,323
    Location
    Adding this to the thisworkbook module will set the print area to the used range each time you print.

    [VBA]Option Explicit
    Private Sub Workbook_BeforePrint(Cancel As Boolean)
    Dim CF As Long, CV As Long, RF As Long, RV As Long
    Dim Col As Long, Rw As Long

    With ActiveSheet
    CF = .Cells.Find(What:="*", After:=Range("A1"), LookIn:=xlFormulas, _
    LookAt:=xlPart, SearchOrder:=xlByColumns, SearchDirection:=xlPrevious).Column
    CV = .Cells.Find(What:="*", After:=Range("A1"), LookIn:=xlValues, _
    LookAt:=xlPart, SearchOrder:=xlByColumns, SearchDirection:=xlPrevious).Column
    RF = .Cells.Find(What:="*", After:=Range("A1"), LookIn:=xlFormulas, _
    LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    RV = .Cells.Find(What:="*", After:=Range("A1"), LookIn:=xlValues, _
    LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row

    Col = Application.WorksheetFunction.Max(CF, CV)
    Rw = Application.WorksheetFunction.Max(RF, RV)

    .PageSetup.PrintArea = "$A$1:" & Cells(Rw, Col).Address
    End With
    End Sub[/VBA]
    Steve
    "Nearly all men can stand adversity, but if you want to test a man's character, give him power."
    -Abraham Lincoln

Posting Permissions

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