Over a decade ago I was working on a very large and complex budget model, come to think of it I still am?
It involved 4 linked Excel workbooks, about 30 worksheets, all different, and multiple views of each worksheet.
There were regular Worksheets and Chart Sheets interspersed throughout.
Some of the Ranges had Outlined/Grouped Totals that were indented on some reports, but not on others depending on whom the various reports were going to.
It was a great budget model until you had to print a copy of it.
And of course the different levels of Managers all want different reports etc, etc.
The Solution
To solve this I developed a simple VBA routine which has evolved over the years to what is presented here.
The basic idea is to add a Printing Control sheet to your workbook.
This sheet has a list of print views, not Excel views, of various pages within the current workbook.
Each page can be setup as you wish and allows for a number of common parameters for each printed page.
Pages can be listed, multiple times if required, with different ranges or outlining selected each time
The Code handles Worksheets and Chartsheets, Normal and Named Ranges, Page Orientation, Page Size, Page Grouping and Headers/Footers.
As a user you setup the sheets as a list in the order you want them, with appropriate parameters.
The code then:
- Loops through the list,
- Obtain the parameters,
- Sets up the print page and
- Prints it.
You just need to sit back and wait for the printer to jam.
HOW DO I USE IT
Download the sample file here Excel 97-03, Excel 2007/10
You can use the sample file as is, for demo purposes or read on later where I describe how to use this in your workbooks.
Open the workbook and Goto the “Print_Control” worksheet.
Browse through the various Headings in Row 4 and field values below them.
Note that some of the Row 4 cells have comments in which explain what options are available.
Each field is described below:
No.
The Row No. in the list of page layouts available.
This has no use except when someone says the 5th page should be…
Description/Header
A text field that is used as a Reminder of the layout of the Page Setup also serves as a Centred Header.
Status
Print = On
Don’t Print = Off
The code only prints the pages marked as On.
Sheet
The name of the Worksheet or Chartsheet you want to print
Area
The Range on the Sheet that you want printed
Ignored for Chartsheets.
Land/Port
Specify if the page should be printed Landscape or Portrait
Ignored for Chartsheets.
Chartsheets are printed in Landscape.
Pages Wide
How many pages wide should the Range be printed on
This is fixed at 1 for Chartsheets.
Pages Tall
How many pages tall should the Range be printed out on
This is fixed at 1 for Chartsheets.
Copies
How Many Copies do you want of that individual page.
Rows & Columns
If outline/grouping is used specify what level of Indentation should be used for the Rows and Columns.
0 – Leave as is
1 – Indent 1 level
8 – Indent 8 levels
The maximum indentation is 8
Ignored for Chartsheets.
Footer (Left)
A description field printed as lower left footer.
No. of Copies
This specifies the Number of Copies of the Whole Report you want
Print All “On” Areas
The Print All “On” Areas Button executes the code and prints out a number of copies of the report as specified in the various page setups.
The printing is done on the default printer on your PC,
Important: Ensure that the printer you want to use for the job is set as the default before you start Excel.
You can print to a PDF file by specifying your Adobe or other PDF Printer as the Default Printer.
I’m sorry, This doesn’t fix the printing multiple pages to multiple files when printing to PDF issue.
Warning ! I maybe old school but I still recommend saving before printing !
HELP
There is limited help built into the system, That’s what this Post is doing.
Some of the field headings have comments which show what values are acceptable in those fields.
HOW DO I ADD THIS TO MY WORKBOOK ?
To add this to your workbook, copy the Print_Control worksheet to your workbook
- Open your workbook.
- Open the Demo File
- Copy the Print_Control worksheet by Right Clicking on the Print_Control tab, and copy to your workbook.
- Run the VBA Code using the “Setup Print Control Named Formula” Button
That’s it.
All the code required for the printing is part of the Print_Control page.
HOW DOES THE VBA WORK ?
The following describes the VBA Code driving this worksheet.
To examine this goto VBA (Alt F11)
Select the workbook and double click on Sheet0 (Print_Control)
The code should appear in the right hand window
If you are unfamiliar with VBA it may be worth going through Chandoo’s Crash Course in VBA
There are 2 Subroutines and a Function in this system which are documented below
Print_Reports
This is the main subroutine that drives the printing
It is called by the Print All On Button and when finished returns the user to the Print_Control worksheet.
All the VBA code is in RED,
Comments and notes are in BLACK before the line or section they refer to.
= = = = = = = = = = = = = = = = = = =
At the start of the Print_Reports subroutine, setup variables for later use
Option Explicit
Public Sub Print_Reports()
Dim PrintArea As Variant
Dim i As Integer
Dim j As Integer
Dim sht As Long
Dim Orientation As String
Dim NCopies As Integer
Dim PWide As Integer
Dim PTall As Integer
Dim Footer As String
Dim Header As String
Dim Sheets As String
Dim gRow As Integer
Dim gCol As Integer
Dim PaperSize As String
Dim msg As String
Dim tmp As String
Turn off the Automatic Calculation so that it is faster and isn’t as jerky
Application.Calculation = xlCalculationManual
This loads the entire array of the Print_Control page into an array called PrintArea
PrintArea = Worksheets(“Print_Control”).Range(“Print_Control”).Value
This sets up a loop for the No of Total Copies of the Whole report
For j = 1 To [Copies].Value ‘Loop through the No of Copies
This sets up a loop for the to check each line of the Print Control area
For i = 1 To UBound(PrintArea, 1) ‘Loop through the print area
If the Column Status is On print using that line of settings
If UCase(PrintArea(i, 3)) = “ON” Then ‘When On is enabled Print using the settings
Extract the settings from the stored array, row i
Header = PrintArea(i, 2) ‘Set Header variable
Orientation = PrintArea(i, 6) ‘Set Orientation variable
PWide = PrintArea(i, 8 ) ‘Set Pages Wide variable
PTall = PrintArea(i, 9) ‘Set Pages Tall variable
NCopies = PrintArea(i, 10) ‘Set No Copies variable
gRow = PrintArea(i, 11) ‘Set Row Group Expansion
gCol = PrintArea(i, 12) ‘Set Column Group Expansion
Footer = PrintArea(i, 13) ‘Set Footer variable
Check paper sizes against the built in page sizes
If PrintArea(i, 7) = “A4” Then
PaperSize = 9
ElseIf PrintArea(i, 7) = “A3” Then
PaperSize = 8
ElseIf PrintArea(i, 7) = “A5” Then
PaperSize = 11
ElseIf PrintArea(i, 7) = “Legal” Then
PaperSize = 5
ElseIf PrintArea(i, 7) = “Letter” Then
PaperSize = 1
ElseIf PrintArea(i, 7) = “Quarto” Then
PaperSize = 15
ElseIf PrintArea(i, 7) = “Executive” Then
PaperSize = 7
ElseIf PrintArea(i, 7) = “B4” Then
PaperSize = 12
ElseIf PrintArea(i, 7) = “B5” Then
PaperSize = 13
ElseIf PrintArea(i, 7) = “10×14” Then
PaperSize = 16
ElseIf PrintArea(i, 7) = “11×17” Then
PaperSize = 17
ElseIf PrintArea(i, 7) = “Csheet” Then
PaperSize = 24
ElseIf PrintArea(i, 7) = “Dsheet” Then
PaperSize = 25
Else
PaperSize = 9 ‘Defaults to A4
End If
Activate the relevant sheet
This checks that the sheet exists first
tmp = PrintArea(i, 4)
SheetExists(tmp) is a UDF that’s checks if the sheet exists and returns True or False
If Not SheetExists(tmp) Then
msg = “Sheet ‘” + PrintArea(i, 4) + “‘ not found.” + vbCrLf + “Check the sheets Name.”
msg = msg + vbCrLf + vbCrLf + “Processing will continue for remaining sheets.”
tmp = MsgBox(msg, vbExclamation, “Sheet not Found”)
Else
The sheet exists now process
Select the sheet
Application.Sheets(PrintArea(i, 4)).Select
Check if it is a Worksheet or a Chartsheet
If ActiveSheet.Type = -4167 Then ‘Its a worksheet
Turn off screen updating
Application.ScreenUpdating = False
Select the relevnt area of the sheet
ActiveSheet.PageSetup.PrintArea = PrintArea(i, 5) ‘Select the relevent Print Area of the Sheet
Set Outline levels
ActiveSheet.Outline.ShowLevels RowLevels:=gRow, ColumnLevels:=gCol ‘Set Outline Grouping
Apply print settings
With ActiveSheet.PageSetup ‘Set print settings
.PrintTitleRows = “”
.PrintTitleColumns = “”
.LeftHeader = “”
.CenterHeader = Header ‘User Defined Header (Shift to Left or Right as required)
.RightHeader = “”
.LeftFooter = Footer ‘User Defined Footer (Shift to Left or Right as required)
.CenterFooter = “”
.RightFooter = “”
.LeftMargin = Application.InchesToPoints(0.1)
.RightMargin = Application.InchesToPoints(0.1)
.TopMargin = Application.InchesToPoints(1.0)
.BottomMargin = Application.InchesToPoints(0.4)
.HeaderMargin = Application.InchesToPoints(0.1)
.FooterMargin = Application.InchesToPoints(0.3)
.PrintHeadings = False
.PrintGridlines = False
.PrintComments = xlPrintNoComments
.CenterHorizontally = False
.CenterVertically = False
.Draft = False
.PaperSize = PaperSize ‘ User Defined Paper Size
.FirstPageNumber = xlAutomatic
.Order = xlDownThenOver
.BlackAndWhite = False
.Zoom = False
.FitToPagesWide = PWide ‘User Defined No Pages Wide
.FitToPagesTall = PTall ‘User Defined No Pages Tall
.PrintErrors = xlPrintErrorsDisplayed
End With
Apply page orientation settings
If Orientation = “L” Then ‘User Defined Page Orientation
ActiveSheet.PageSetup.Orientation = xlLandscape
Else
ActiveSheet.PageSetup.Orientation = xlPortrait
End If
Turn Screen updating back on
Application.ScreenUpdating = True
Finished setting up Worksheet goto the Printing area
Else ‘Its a Chart page
Turn Screen updating off
Application.ScreenUpdating = False
Apply print settings
With ActiveChart.PageSetup
.LeftHeader = “”
.CenterHeader = Header
.RightHeader = “”
.LeftFooter = Footer
.CenterFooter = “”
.RightFooter = “”
.LeftMargin = Application.InchesToPoints(0.1)
.RightMargin = Application.InchesToPoints(0.1)
.TopMargin = Application.InchesToPoints(1#)
.BottomMargin = Application.InchesToPoints(0.4)
.HeaderMargin = Application.InchesToPoints(0.1)
.FooterMargin = Application.InchesToPoints(0.3)
.ChartSize = xlScreenSize
.PrintQuality = 600 ‘Change to 300 for Excel 97-03
.CenterHorizontally = True
.CenterVertically = True
.Orientation = xlLandscape
.Draft = False
.OddAndEvenPagesHeaderFooter = False ‘Removed from 97/03 Ver
.DifferentFirstPageHeaderFooter = False ‘Removed from 97/03 Ver
.EvenPage.LeftHeader.Text = “” ‘Removed from 97/03 Ver
.EvenPage.CenterHeader.Text = “” ‘Removed from 97/03 Ver
.EvenPage.RightHeader.Text = “” ‘Removed from 97/03 Ver
.EvenPage.LeftFooter.Text = “” ‘Removed from 97/03 Ver
.EvenPage.CenterFooter.Text = “” ‘Removed from 97/03 Ver
.EvenPage.RightFooter.Text = “” ‘Removed from 97/03 Ver
.FirstPage.LeftHeader.Text = “” ‘Removed from 97/03 Ver
.FirstPage.CenterHeader.Text = “” ‘Removed from 97/03 Ver
.FirstPage.RightHeader.Text = “” ‘Removed from 97/03 Ver
.FirstPage.LeftFooter.Text = “” ‘Removed from 97/03 Ver
.FirstPage.CenterFooter.Text = “” ‘Removed from 97/03 Ver
.FirstPage.RightFooter.Text = “” ‘Removed from 97/03 Ver
.PaperSize = PaperSize
.FirstPageNumber = xlAutomatic
.BlackAndWhite = False
.Zoom = 100
End With
Turn Screen Updating back on
Application.ScreenUpdating = True
End If
Now Print the active sheet using user defined No. Copies
ActiveWindow.SelectedSheets.PrintOut Copies:=NCopies, Collate:=True
End If
End If
Next i
Next j
Clear PrintArea array, just in case
PrintArea = Null
Turn Auto Calculation back on
Application.Calculation = xlCalculationAutomatic
Go back to the Print Control sheet
Application.Sheets(“Print_Control”).Select
End Sub
= = = = = = = = = = = = = = = = = = =
The SheetExists Function
This is a Function that is used by the Print_Reports subroutine to check if a sheet exists.
= = = = = = = = = = = = = = = = = = =
Function SheetExists(SheetName As String) As Boolean
‘ This function Returns TRUE if the sheet exists in the active workbook
SheetExists = False ‘Set default value of SheetExists
On Error GoTo NoSuchSheet ‘Set error trapping such that if the sheet doesn’t exist it will exit
Check length of sheet name, if the sheet exists it will return a value, otherwise an error
If Len(Sheets(SheetName).Name) > 0 Then
The sheet exists so set SheetExists = True and exit
SheetExists = True
Exit Function
End If
NoSuchSheet:
The sheet doesn’t exists so use default SheetExists = False and exit
End Function
= = = = = = = = = = = = = = = = = = =
The Setup_Print_Control_Named_Formula Subroutine
This is a simple subroutine that sets up the 2 named formula for use the first time a sheet is used.
= = = = = = = = = = = = = = = = = = =
Sub Setup_Print_Control_Named_Formula()
Setup Named Formula “Print_Control” which is the table of settings
ActiveWorkbook.Names.Add Name:=”Print_Control”, RefersToR1C1:= _
“=OFFSET(Print_Control!R4C2,1,,COUNTA(Print_Control!R5C2:R24C2),COUNTA(Print_Control!R4))”
ActiveWorkbook.Names(“Print_Control”).Comment = _
“Used by the Print_Reports Subroutine”
Setup Named Formula “Copies” which is the No of Copies of the Whole Report
ActiveWorkbook.Names.Add Name:=”Copies”, RefersToR1C1:= _
“=Print_Control!R26C13”
ActiveWorkbook.Names(“Copies”).Comment = “Specifies the No. of Copies for the Print_Reports Subroutine”
End Sub
= = = = = = = = = = = = = = = = = = =
NAMED FORMULA
The code relies on two Named Formulas
Copies:
=Print_Control!$L$27
Print_Control:
=OFFSET(Print_Control!$B$4,1,,COUNTA(Print_Control!$B$5:$B$24),COUNTA(Print_Control!$4:$4))
Automatically adjusts the Print_Control Named Formula for the number of Page Setup lines and Fields to be processed
If you have queries about how any of the above code works, please let me know in the comments below:
WHAT DOES THE ARRAY “PrintArea” DO ?
The print area array stores the values of the Print_Control range in a 2 dimensional array which represents the Print_Control range.
This is done for a few reasons, but simply it is faster as it results in less reading of the worksheet
It also allows more flexibility in the subsequent processing as all the data is in one area.
DOWNLOADS
Download the sample file here Excel 97-03, Excel 2007/10
WHAT’S NEXT
There are a number of parameters used in the Print Setup area which are not used or not used in the 97/03 version.
The code above is easily extended to include these if you desire.
One day when I have a spare moment (Most likely in 2025!) I will add the option for automatic incremental Page Numbers.
CLOSING
This code has saved, my staff and I, hundreds and hundreds of hours over the past decade whilst printing complex Excel workbooks.
This functionality was also one of the more requested issues from our poll of 3 months ago We Want Your Ideas!
I hope you enjoy it as much as I have ?
Updates
I will be extending the functionality of this in the future and so if you have any suggestions, lets hear them in the comments below:
How have you tackled large print jobs ?
I look forward to your comments below:
Hui…
For a list of my other contributions at Chandoo.org please visit; Hui.
21 Responses to “Make a Pivot Table in Excel [15 Second Tutorial]”
[...] First step is to create Pivot Table. Here is a video tutorial on making pivot tables. [...]
Dear Sir,
I would like to study pivot table from basics detailed.Pls send me the tips of that
merccccccccccccccccccccccccccccccccccccc
[...] Click here to see a video tutorial of making pivot tables in excel | One more Pivot Table Video Tutorial [...]
it is very useful
hello sir
please send me some information of pivotable. and how to use it
because I am beginer so how can i learn it the pivotable.
and sir will you send me pivotable data because i have no data and i don't
know how to applyed for the pivotable. give some videos so I learn quikely.
thank you
and my best
anticipation
Hi,
This tutorail was helpful. If possible can you please email me some data, so I can create another pivot table? I am trying to learn ASAP and need some info.
Thank you
@Keri
Have a look at FakeNameGenerator.com
Top of the day to you. can you pls send me a detailed tutorial on the pivot table tutorial? Thanks.
Hi,
please tell me how to use Pivot table.
@Karthick, Yemi
Have a read of: http://chandoo.org/wp/2009/08/19/excel-pivot-tables-tutorial/
Dear Sir,
I visited this website of urs for the very first time and trust me this is fabulous.i learnt pivot table through this.Thanks a lot.In corporate world nobody gonna make u learn these things.m very grateful to u.This is a great initiative from ur side.Commendable job done.Hats off to u.For beginners also this is very helpful.The way this website makes u learn excel is very good.
Pooja
Can you please email me information to put into a pivot table and possibly a complete set of instructions? I am a beginner to pivot tables and am possibly interested in obtaining a position that requires pivot tables. thank you.
[...] Click here to see a video tutorial of making pivot tables in excel | One more Pivot Table Video Tutorial [...]
It's simply great..!!
Cool!
Fast but not furious.
Pls email me details of pivot table. I want to learn it asap because I just got a job that requires this. Thanks
it is very useful..............thanks
Sir please can u send me the complete explanation of pivot tables from basics
hello,
I wanted to know how to put pivot with emp id, emp name, emp position in one row.
Ex:-
cel A4 should have Emp id
Cell B4 should have Emp Name
Call C4 should have Emp Position
many thanks in advance
Nice information, thanx my dear.