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