Macro for Creating PDF based on Cell Value

Chandresh

Board Regular
Joined
Jul 21, 2009
Messages
101
Hi Team,

Can anyone help me with a macro which will create diffrent PDF for each page in a sheet and name it based on cell value and save in folder on desktop.

Example : i have one sheet with 30 pages in it all page have similar format. i need a macro which will create diffrent pdf and name it based on cell X4(X4+30 for next Page) then after it should loop till 30th Page.

Thanks
Chan
 

John_w

MrExcel MVP
Joined
Oct 15, 2007
Messages
5,999
Try this macro. You will see that it assumes the first page starts at row 1 (in the active sheet of the active workbook). It creates the PDF files in the "PDFs" subfolder on your Desktop; this subfolder is created if it doesn't exist.
Code:
Public Sub Create_PDF_For_Each_Page()

    Dim ws As Worksheet
    Dim lastRow As Long, pageStartRow As Long
    Dim page As Long
    Dim fileNameCell As Range
    Dim saveInFolder As String
    Dim PDFrange As Range
    Dim PDFfile As String
    
    saveInFolder = CreateObject("WScript.Shell").SpecialFolders("Desktop") & "\PDFs\"
    If Right(saveInFolder, 1) <> "\" Then saveInFolder = saveInFolder & "\"
    If Dir(saveInFolder, vbDirectory) = vbNullString Then MkDir saveInFolder
    
    'Process pages on the active sheet in the active workbook
    
    Set ws = ActiveWorkbook.ActiveSheet
        
    With ws
        
        lastRow = .Cells(.Rows.Count, "A").End(xlUp).Row
        pageStartRow = 1                        'first page starts at row 1
        Set fileNameCell = .Range("X4")         'cell containing file name (without .pdf extension) of first page
        
        'Save rows in each horizontal page break section as PDF file with file name in X4, X34, X64, etc.
        
        For page = 1 To .HPageBreaks.Count
            
            PDFfile = saveInFolder & fileNameCell.Value & ".pdf"
            Set PDFrange = .Rows(pageStartRow & ":" & .HPageBreaks(page).Location.Row - 1).EntireRow
            
            PDFrange.ExportAsFixedFormat Type:=xlTypePDF, Filename:=PDFfile, _
                Quality:=xlQualityStandard, IncludeDocProperties:=True, IgnorePrintAreas:=False, OpenAfterPublish:=False
            
            Set fileNameCell = fileNameCell.Offset(30)
            pageStartRow = .HPageBreaks(page).Location.Row
            
        Next
    
        If pageStartRow <= lastRow Then
        
            'Save rows after last horizontal page break as PDF file
            
            PDFfile = saveInFolder & fileNameCell.Value & ".pdf"
            Set PDFrange = .Rows(pageStartRow & ":" & lastRow).EntireRow
            
            PDFrange.ExportAsFixedFormat Type:=xlTypePDF, Filename:=PDFfile, _
                Quality:=xlQualityStandard, IncludeDocProperties:=True, IgnorePrintAreas:=False, OpenAfterPublish:=False
            
        End If
    
    End With
    
    MsgBox "Created PDFs in " & saveInFolder
    
End Sub
 

Chandresh

Board Regular
Joined
Jul 21, 2009
Messages
101
HI thanks for the code .

it created the first PDF however unable to create the others ,could you please help
it says
run-time error -2147024773 (8007007b)

 

John_w

MrExcel MVP
Joined
Oct 15, 2007
Messages
5,999
Which line causes that error? Click Debug on the error message and the errant line is highlighted in yellow.
 

Forum statistics

Threads
1,082,298
Messages
5,364,375
Members
400,793
Latest member
hamzayagiz

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top