Macro - Set Print Area for Changing Data Area

K

ksp

Hi All

I have an Excel 2003 spreadsheet that has data that is dumped from
another application. I wanted to automate setting the print area each
time the user creates the file, my problem is that the amount of data
is not fixed and will change everytime they update the info.

I can't assume that there will always be text in the last cell in the
bottom right hand corner as this cell may be blank. However, the
spreadsheet print area will always be 7 columns wide, and the last cell
in Column D will always have data.

Does anybody have any idea o fhow to do this ?

Ta

Karen
 
L

Leith Ross

Hello Karen,

You don't say which 7 columns you are using, so I am going to use A t
G in this example. You can change it later if you need to. Insert a VB
module into your workbook and paste this code into it. You can create
button to call this macro for you, or simply run it from the Macro Lis
by pressing ALT + F8 and selecting it.


Code
-------------------
Public Sub AutoSetPrintArea()

Dim LastRow As Long

With ActiveSheet
LastRow = .Cells(.Rows.Count, "D").End(xlUp)
.PageSetup.PrintArea = "A1:G" & LastRow
End With

End Sub
 
K

ksp

Hi Leigh

Thanks for the info (Good assumption - yes it was columns A to G)

I have copied and pasted your code into a new module, but when I try to
run the macro I get a run time error '13', type mismatch

If I click on debug this is the line that is highlighted

LastRow = .Cells(.Rows.Count, "D").End(xlUp)

Are you able to shed any light on this ?

Thanks

Karen
 
L

Leith Ross

Hello Karen,

Sorry about that. I made a typo. I'll correct the post also.

Change that line to...
LastRow = .Cells(.Rows.Count, "D").End(xlUp).Row

Sincerely,
Leith Ross
 
K

ksp

Leith

You're a champion - it works a treat

Thanks heaps for that I really appreciate it

Ta

Karen
 
T

Troy

Excellent post, I used this to solve a problem I was having and wanted to
share a variation.

I have a similar situation except I copy many different bunches of data to
many different worksheets. The following function will leave the existing
print settings the same (assuming you set them up once), but changes the end
row of the print range to fit the current data set.

Sub UpdatePrintAreas()
'example function call, I use range names because the worksheet
names/positions change

AutoSetPrintArea Range("CopyFunctionData")
AutoSetPrintArea Range("CopyProcessData")
AutoSetPrintArea Range("CopyFinancialData")
End Sub


Function AutoSetPrintArea(MyRange As Range)

Dim LastRow As Long

With MyRange.Worksheet
LastRow = .Cells(.Rows.Count, "D").End(xlUp).Row
.PageSetup.PrintArea = Left(.PageSetup.PrintArea,
Len(.PageSetup.PrintArea) - 2) & LastRow
End With

End Function
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Similar Threads


Top