6
votes

I'm trying to convert a Google spreadsheet with multiple sheets to a PDF file. The script below works, but it only creates a PDF with the last page of the spreadsheet.

function savePDFs() {
    SpreadsheetApp.flush();

    var ss = SpreadsheetApp.getActiveSpreadsheet();
    var sheets = ss.getSheets();
    var url = ss.getUrl();

    //remove the trailing 'edit' from the url
    url = url.replace(/edit$/,'');

    //additional parameters for exporting the sheet as a pdf
    var url_ext = 'export?exportFormat=pdf&format=pdf' + //export as pdf

    //below parameters are optional...
    '&size=letter' + //paper size
    '&portrait=false' + //orientation, false for landscape
    '&fitw=true' + //fit to width, false for actual size
    '&sheetnames=false&printtitle=false&pagenumbers=false' + //hide optional
    '&gridlines=false' + //false = hide gridlines
    '&fzr=false' + //do not repeat row headers (frozen rows) on each page
    '&gid='; //leave ID empty for now, this will be populated in the FOR loop

    var token = ScriptApp.getOAuthToken();

    //make an empty array to hold your fetched blobs
    var blobs = [];

    //.fetch is called for each sheet, the response is stored in var blobs[]
    for(var i = 0; i < sheets.length; i++) {
        var sheetname = sheets[i].getName();

        //if the sheet is one that you don't want to process,
        //continue' tells the for loop to skip this iteration of the loop
        if(sheetname == "Team Member Numbers")
            continue;

        //grab the blob for the sheet
        var response = UrlFetchApp.fetch(url + url_ext + sheets[i].getSheetId(), {
            headers: {
                'Authorization': 'Bearer ' +  token
            }
        });

        //convert the response to a blob and store in our array
        blobs.push(response.getBlob().setName(sheets[i].getName() + '.pdf'));
        var array_blob = response.getBlob().setName(sheets[i].getName() + '.pdf');
    }

    //from here you should be able to use and manipulate the blob to send and
    //email or create a file per usual.

    // send email
    var subject = "Enter Subject"
    var message = "See attached PDF"
    MailApp.sendEmail("email addy here", subject, message,{attachments:[array_blob]});
}
4
@NathanHughes - this question is about all sheets in a spreadsheet, while previous was about a single sheet. Subtle difference, but not duplicate, imo. Further, since the time of the accepted answer on other question, the OAuth story became much simpler - not that it changes the question, but people are less likely to adapt code from closed questions, so we might do a disservice by closing this one. (Regardless, I tacked the answer on both to make it easy for others to find.)Mogsdad
@Mogsdad: thanks for the clarification, I retracted my close vote.Nathan Hughes
NOTE: This doesn't work if the sheet is hidden. Use activate() to unhide a sheet.Andrew Roberts

4 Answers

8
votes

I've tweaked @Mogsdad code slightly to print the entire spreadsheet as one PDF. The key is tweaking the export parameter. Basically replace

'&gid=' + sheet.getSheetId()   //the sheet's Id

with

(optSheetId ? ('&gid=' + sheet.getSheetId()) : ('&id=' + ss.getId()))  // Print either the entire Spreadsheet or the specified sheet if optSheetId is provided

So the code above minus the looping looks like:

function savePDFs( optSSId, optSheetId ) {

  // If a sheet ID was provided, open that sheet, otherwise assume script is
  // sheet-bound, and open the active spreadsheet.
  var ss = (optSSId) ? SpreadsheetApp.openById(optSSId) : SpreadsheetApp.getActiveSpreadsheet();

  // Get folder containing spreadsheet, for later export
  var parents = DriveApp.getFileById(ss.getId()).getParents();
  if (parents.hasNext()) {
    var folder = parents.next();
  }
  else {
    folder = DriveApp.getRootFolder();
  }

  //additional parameters for exporting the sheet as a pdf
  var url_ext = 'export?exportFormat=pdf&format=pdf'   //export as pdf

      // Print either the entire Spreadsheet or the specified sheet if optSheetId is provided
      + (optSheetId ? ('&gid=' + sheet.getSheetId()) : ('&id=' + ss.getId()))

      // following parameters are optional...
      + '&size=letter'      // paper size
      + '&portrait=true'    // orientation, false for landscape
      + '&fitw=true'        // fit to width, false for actual size
      + '&sheetnames=false&printtitle=false&pagenumbers=false'  //hide optional headers and footers
      + '&gridlines=false'  // hide gridlines
      + '&fzr=false';       // do not repeat row headers (frozen rows) on each page

  var options = {
    headers: {
      'Authorization': 'Bearer ' +  ScriptApp.getOAuthToken()
    }
  }
  var response = UrlFetchApp.fetch("https://docs.google.com/spreadsheets/" + url_ext, options);
  var blob = response.getBlob().setName(ss.getName() + '.pdf');

  //from here you should be able to use and manipulate the blob to send and email or create a file per usual.
  //In this example, I save the pdf to drive
  folder.createFile(blob);

}

Btw, thank you -- I've been looking for a solution for this for a long time!

5
votes

This function is an adaptation of a script provided by "ianshedd..." here.

It:

  • Generates PDFs of ALL sheets in a spreadsheet, and stores them in the same folder containing the spreadsheet. (It assumes there's just one folder doing that, although Drive does allow multiple containment.)

  • Names pdf files with Spreadsheet & Sheet names.

  • Uses the Drive service (DocsList is deprecated.)

  • Can use an optional Spreadsheet ID to operate on any sheet. By default, it expects to work on the "active spreadsheet" containing the script.

  • Needs only "normal" authorization to operate; no need to activate advanced services (well... you do need some, see this) or fiddle with oAuthConfig.

    OAuth2 Authorization for the fetch() call that retrieves the PDF of a spreadsheet is granted via ScriptApp.getOAuthToken(), which gives us the OAuth 2.0 access token for the current user.

With a bit of research and effort, you could hook up to an online PDF Merge API, to generate a single PDF file. Barring that, and until Google provides a way to export all sheets in one PDF, you're stuck with separate files. See Gilbert's tweak for a way to get multiple sheets!

Script:

/**
 * Export one or all sheets in a spreadsheet as PDF files on user's Google Drive,
 * in same folder that contained original spreadsheet.
 *
 * Adapted from https://code.google.com/p/google-apps-script-issues/issues/detail?id=3579#c25
 *
 * @param {String}  optSSId       (optional) ID of spreadsheet to export.
 *                                If not provided, script assumes it is
 *                                sheet-bound and opens the active spreadsheet.
 * @param {String}  optSheetId    (optional) ID of single sheet to export.
 *                                If not provided, all sheets will export.
 */
function savePDFs( optSSId, optSheetId ) {

  // If a sheet ID was provided, open that sheet, otherwise assume script is
  // sheet-bound, and open the active spreadsheet.
  var ss = (optSSId) ? SpreadsheetApp.openById(optSSId) : SpreadsheetApp.getActiveSpreadsheet();
  
  // Get URL of spreadsheet, and remove the trailing 'edit'
  var url = ss.getUrl().replace(/edit$/,'');

  // Get folder containing spreadsheet, for later export
  var parents = DriveApp.getFileById(ss.getId()).getParents();
  if (parents.hasNext()) {
    var folder = parents.next();
  }
  else {
    folder = DriveApp.getRootFolder();
  }
  
  // Get array of all sheets in spreadsheet
  var sheets = ss.getSheets();
  
  // Loop through all sheets, generating PDF files.
  for (var i=0; i<sheets.length; i++) {
    var sheet = sheets[i];
    
    // If provided a optSheetId, only save it.
    if (optSheetId && optSheetId !== sheet.getSheetId()) continue; 
    
    //additional parameters for exporting the sheet as a pdf
    var url_ext = 'export?exportFormat=pdf&format=pdf'   //export as pdf
        + '&gid=' + sheet.getSheetId()   //the sheet's Id
        // following parameters are optional...
        + '&size=letter'      // paper size
        + '&portrait=true'    // orientation, false for landscape
        + '&fitw=true'        // fit to width, false for actual size
        + '&sheetnames=false&printtitle=false&pagenumbers=false'  //hide optional headers and footers
        + '&gridlines=false'  // hide gridlines
        + '&fzr=false';       // do not repeat row headers (frozen rows) on each page

    var options = {
      headers: {
        'Authorization': 'Bearer ' +  ScriptApp.getOAuthToken()
      }
    }

    var response = UrlFetchApp.fetch(url + url_ext, options);
    
    var blob = response.getBlob().setName(ss.getName() + ' - ' + sheet.getName() + '.pdf');

    //from here you should be able to use and manipulate the blob to send and email or create a file per usual.
    //In this example, I save the pdf to drive
    folder.createFile(blob);
  }
}

/**
 * Dummy function for API authorization only.
 * From: https://stackoverflow.com/a/37172203/1677912
 */
function forAuth_() {
  DriveApp.getFileById("Just for authorization"); // https://code.google.com/p/google-apps-script-issues/issues/detail?id=3579#c36
}
3
votes

I do not yet have the reputation to comment, but there seems to be a minor issue with the top answer above as submitted by Gilbert W... though it's just as likely that I failed to understand something.

That solution includes the line

  + (optSheetId ? ('&gid=' + sheet.getSheetId()) : ('&id=' + ss.getId()))

However, "sheet" has not been defined in the code prior to this point. In Mogsdad's code, "sheet" is defined within the loop that was removed:

for (var i=0; i<sheets.length; i++) {
var sheet = sheets[i];

And "sheets" was defined as

var sheets = ss.getSheets();

The solution works for someone who wants to print the entire spreadsheet, which is the question that was asked. However, the code no longer works for someone who wants to print a single page.

Another issue with Gilbert's updated code was that the HTML request included a reference to the sheet ID, but not the spreadsheet itself. This caused the response to fail if you provided a specific sheet ID, though it works fine if no sheet ID was provided. I got it to work again by reverting the URL base to the way Mogsdad had it.

Another tweak: Gilbert's code automatically names the new .PDF as whatever the spreadsheet was named. Meanwhile, Mogsdad's code prints out every sheet one at a time, naming each .PDF with the spreadsheet name followed by the name of the current sheet. I wanted to print the PDF with the name of the single sheet, if applicable, and also provide the user the ability to specify an output name.

Since no method exists to "getSheetById", depending on the context of your code, it probably makes more sense for the function to take "optSheetName" instead of "optSheetID." The sheet ID can be grabbed from "getSheetByName" if needed, and it seems to me a user is generally more likely to have the sheet's name than the sheet's ID. Both the name and the ID can be obtained programmatically from a bound script, but only the name can be used to get a specific existing sheet.

I also added an optional email parameter so that you can print and email the PDF at the same time.

Here is my version:

function savePDFs( optSSId , optSheetName , optOutputName, optEmail) {

  // If a sheet ID was provided, open that sheet, otherwise assume script is
  // sheet-bound, and open the active spreadsheet.
  var ss = (optSSId) ? SpreadsheetApp.openById(optSSId) : SpreadsheetApp.getActiveSpreadsheet();
  var optSheetId = ss.getSheetByName(optSheetName).getSheetId();
  var outputName = (optOutputName ? optOutputName : (optSheetName ? optSheetName : ss.getName())) 

  // Get folder containing spreadsheet, for later export
  var parents = DriveApp.getFileById(ss.getId()).getParents();
  if (parents.hasNext()) {
    var folder = parents.next();
  }
  else {
    folder = DriveApp.getRootFolder();
  }

  var url_base = ss.getUrl().replace(/edit$/,'');

  //additional parameters for exporting the sheet as a pdf
  var url_ext = 'export?exportFormat=pdf&format=pdf'   //export as pdf

      // Print either the entire Spreadsheet or the specified sheet if optSheetId is provided
      + (optSheetId ? ('&gid=' + optSheetId) : ('&id=' + ss.getId()))      // Print either the entire Spreadsheet or the specified sheet if optSheetId is provided
      // following parameters are optional...
      + '&size=letter'      // paper size
      + '&portrait=true'    // orientation, false for landscape
      + '&fitw=true'        // fit to width, false for actual size
      + '&sheetnames=false&printtitle=false&pagenumbers=false'  //hide optional headers and footers
      + '&gridlines=false'  // hide gridlines
      + '&fzr=false';       // do not repeat row headers (frozen rows) on each page

  var options = {
    headers: {
      'Authorization': 'Bearer ' +  ScriptApp.getOAuthToken(),
    }
  }
  var response = UrlFetchApp.fetch(url_base + url_ext, options);
  var blob = response.getBlob().setName((outputName)+ '.pdf');
  folder.createFile(blob);

  GmailApp.sendEmail(optEmail, "Here is a file named " + outputName, "Please let me know if you have any questions or comments.", {attachments:blob});
} 
1
votes

Here's my variation on this theme, based on Dr Queso's answer.

All parameters (described in the code) are optional and if none are specified it uses the active spreadsheet, converts all of the tabs into a single PDF named after the spreadsheet and doesn't email the PDF.

function test() {

  // Create a PDF containing all the tabs in the active spreadsheet, name it
  // after the spreadsheet, and email it
  convertSpreadsheetToPdf('[email protected]')

  // Create a PDF containing all the tabs in the spreadsheet specified, name it
  // after the spreadsheet, and email it
  convertSpreadsheetToPdf('[email protected]', '1r9INcnsyvSQmeduJWVYAvznOOYei9jeAjsy0acA3G1k')

  // Create a PDF just containing the tab 'Sheet2' in the active spreadsheet, specify a name, and email it
  convertSpreadsheetToPdf('[email protected]', null, 'Sheet2', 'PDF 3')
}

/*
 * Save spreadsheet as a PDF
 *     
 * @param {String} email Where to send the PDF [OPTIONAL] 
 * @param {String} spreadsheetId Or the active spreadsheet[OPTIONAL]
 * @param {String} sheetName The tab to output [OPTIONAL]
 * @param {String} PdfName [OPTIONAL]
 */

function convertSpreadsheetToPdf(email, spreadsheetId, sheetName, pdfName) {

  var spreadsheet = spreadsheetId ? SpreadsheetApp.openById(spreadsheetId) : SpreadsheetApp.getActiveSpreadsheet();
  spreadsheetId = spreadsheetId ? spreadsheetId : spreadsheet.getId()  
  var sheetId = sheetName ? spreadsheet.getSheetByName(sheetName).getSheetId() : null;  
  var pdfName = pdfName ? pdfName : spreadsheet.getName();
  var parents = DriveApp.getFileById(spreadsheetId).getParents();
  var folder = parents.hasNext() ? parents.next() : DriveApp.getRootFolder();
  var url_base = spreadsheet.getUrl().replace(/edit$/,'');

  var url_ext = 'export?exportFormat=pdf&format=pdf'   //export as pdf

      // Print either the entire Spreadsheet or the specified sheet if optSheetId is provided
      + (sheetId ? ('&gid=' + sheetId) : ('&id=' + spreadsheetId)) 
      // following parameters are optional...
      + '&size=letter'      // paper size
      + '&portrait=true'    // orientation, false for landscape
      + '&fitw=true'        // fit to width, false for actual size
      + '&sheetnames=false&printtitle=false&pagenumbers=false'  //hide optional headers and footers
      + '&gridlines=false'  // hide gridlines
      + '&fzr=false';       // do not repeat row headers (frozen rows) on each page

  var options = {
    headers: {
      'Authorization': 'Bearer ' +  ScriptApp.getOAuthToken(),
    }
  }

  var response = UrlFetchApp.fetch(url_base + url_ext, options);
  var blob = response.getBlob().setName(pdfName + '.pdf');
  folder.createFile(blob);

  if (email) {

    var mailOptions = {
      attachments:blob
    }

    MailApp.sendEmail(
      email, 
      "Here is a file named " + pdfName, 
      "Please let me know if you have any questions or comments.", 
      mailOptions);
  }

} // convertSpreadsheetToPdf()

NOTE: This doesn't work if the sheet is hidden. Use activate() to unhide a sheet.