產生及傳送 Google 試算表的 PDF 檔案

程式設計程度:初學者
時間長度:15 分鐘
專案類型:使用自訂選單的自動化功能

目標

  • 瞭解解決方案的功能。
  • 瞭解 Apps Script 服務在解決方案中的作用。
  • 設定指令碼。
  • 執行指令碼。

認識這項解決方案

您可以在 Google 試算表中,將工作表的資訊自動建立成 PDF。生成後,即可直接從 Google 試算表用電子郵件傳送 PDF。這個解決方案著重於建立自訂應付憑據,不過您也能依需求更新範本和指令碼。

應付憑據範本的螢幕截圖

運作方式

指令碼會使用「月結單範本」工作表做為生成 PDF 的範本。並從其他工作表擷取資訊,填妥範本中的特定儲存格。以電子郵件傳送 PDF 時,指令碼會反覆利用月結單工作表,取得 PDF 連結和相關電子郵件地址。在傳送電子郵件前,指令碼會建立一般電子郵件主旨和內文,並附上 PDF。

Apps Script 服務

本解決方案會使用下列服務:

  • 試算表服務:提供產生應付憑據 PDF 和建立電子郵件所需的所有資訊。當使用者在自訂選單中按一下「Reset template」(重設範本) 時,清除範本中的資料。
  • 公用事業服務:在逐一處理每位客戶時,使用 sleep() 方法暫停指令碼,以確保每張帳單都會加入正確的資訊。
  • 網址擷取服務:將「月結單範本」工作表匯出為 PDF。
  • 指令碼服務:授權網址擷取服務存取試算表。
  • 雲端硬碟服務:為匯出的 PDF 檔案建立資料夾。將 PDF 檔案附加到電子郵件中。
  • Gmail 服務:建立及傳送電子郵件。

必要條件

如要使用這個範例,您必須具備下列先決條件:

  • Google 帳戶 (Google Workspace 帳戶可能需要管理員核准)。
  • 可連上網際網路的網路瀏覽器。

設定指令碼

  1. 按一下下方按鈕,複製「從 Google 試算表產生並傳送 PDF」試算表。這個解決方案的 Apps Script 專案已附加至試算表。
    「建立副本」

  2. 依序按一下「擴充功能」>「Apps Script」

  3. Code.gs 檔案中,更新下列變數:

    1. EMAIL_OVERRIDE 設為 true
    2. EMAIL_ADDRESS_OVERRIDE 設為您的電子郵件地址。
  4. 按一下「儲存」圖示 「儲存」圖示

執行指令碼

  1. 返回試算表,然後依序點選「產生並傳送 PDF」>「處理應付憑據」
  2. 出現提示時,請授權執行指令碼。如果 OAuth 同意畫面顯示「This app isn't verified」警告,請依序選取「Advanced」「Go to {Project Name} (unsafe)」(前往「{Project Name}」(不安全))。

  3. 依序點選「產生並傳送 PDF」>「處理月結單」

  4. 如要查看 PDF 檔案,請切換至「月結單」工作表,然後按一下「月結單連結」欄中的連結。

  5. 依序點選「產生並傳送 PDF 檔案」>「傳送電子郵件」

  6. 請查看電子郵件,瞭解電子郵件和附件 PDF 檔案。由於您在上一節將 EMAIL_OVERRIDE 設為 true,因此指令碼會將所有電子郵件傳送至您為 EMAIL_ADDRESS_OVERRIDE 指定的電子郵件地址。如果將 EMAIL_OVERRIDE 設為 false,指令碼會將電子郵件傳送至「Customers」工作表中列出的電子郵件地址。

  7. (選用) 如要清除「月結單範本」工作表中的資料,請依序點選「產生並傳送 PDF 檔案」>「重設範本」

查看程式碼

如要查看這個解決方案的 Apps Script 程式碼,請按一下下方的「查看原始碼」

查看原始碼

Code.gs

solutions/automations/generate-pdfs/Code.js
// To learn how to use this script, refer to the documentation:
// https://developers.google.com/apps-script/samples/automations/generate-pdfs

/*
Copyright 2022 Google LLC

Licensed under the Apache License, Version 2.0 (the "License");
you may not use this file except in compliance with the License.
You may obtain a copy of the License at

    https://www.apache.org/licenses/LICENSE-2.0

Unless required by applicable law or agreed to in writing, software
distributed under the License is distributed on an "AS IS" BASIS,
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
See the License for the specific language governing permissions and
limitations under the License.
*/

// TODO: To test this solution, set EMAIL_OVERRIDE to true and set EMAIL_ADDRESS_OVERRIDE to your email address.
const EMAIL_OVERRIDE = false;
const EMAIL_ADDRESS_OVERRIDE = 'test@example.com';

// Application constants
const APP_TITLE = 'Generate and send PDFs';
const OUTPUT_FOLDER_NAME = "Customer PDFs";
const DUE_DATE_NUM_DAYS = 15

// Sheet name constants. Update if you change the names of the sheets.
const CUSTOMERS_SHEET_NAME = 'Customers';
const PRODUCTS_SHEET_NAME = 'Products';
const TRANSACTIONS_SHEET_NAME = 'Transactions';
const INVOICES_SHEET_NAME = 'Invoices';
const INVOICE_TEMPLATE_SHEET_NAME = 'Invoice Template';

// Email constants
const EMAIL_SUBJECT = 'Invoice Notification';
const EMAIL_BODY = 'Hello!\rPlease see the attached PDF document.';


/**
 * Iterates through the worksheet data populating the template sheet with 
 * customer data, then saves each instance as a PDF document.
 * 
 * Called by user via custom menu item.
 */
function processDocuments() {
  const ss = SpreadsheetApp.getActiveSpreadsheet();
  const customersSheet = ss.getSheetByName(CUSTOMERS_SHEET_NAME);
  const productsSheet = ss.getSheetByName(PRODUCTS_SHEET_NAME);
  const transactionsSheet = ss.getSheetByName(TRANSACTIONS_SHEET_NAME);
  const invoicesSheet = ss.getSheetByName(INVOICES_SHEET_NAME);
  const invoiceTemplateSheet = ss.getSheetByName(INVOICE_TEMPLATE_SHEET_NAME);

  // Gets data from the storage sheets as objects.
  const customers = dataRangeToObject(customersSheet);
  const products = dataRangeToObject(productsSheet);
  const transactions = dataRangeToObject(transactionsSheet);

  ss.toast('Creating Invoices', APP_TITLE, 1);
  const invoices = [];

  // Iterates for each customer calling createInvoiceForCustomer routine.
  customers.forEach(function (customer) {
    ss.toast(`Creating Invoice for ${customer.customer_name}`, APP_TITLE, 1);
    let invoice = createInvoiceForCustomer(
      customer, products, transactions, invoiceTemplateSheet, ss.getId());
    invoices.push(invoice);
  });
  // Writes invoices data to the sheet.
  invoicesSheet.getRange(2, 1, invoices.length, invoices[0].length).setValues(invoices);
}

/**
 * Processes each customer instance with passed in data parameters.
 * 
 * @param {object} customer - Object for the customer
 * @param {object} products - Object for all the products
 * @param {object} transactions - Object for all the transactions
 * @param {object} invoiceTemplateSheet - Object for the invoice template sheet
 * @param {string} ssId - Google Sheet ID     
 * Return {array} of instance customer invoice data
 */
function createInvoiceForCustomer(customer, products, transactions, templateSheet, ssId) {
  let customerTransactions = transactions.filter(function (transaction) {
    return transaction.customer_name == customer.customer_name;
  });

  // Clears existing data from the template.
  clearTemplateSheet();

  let lineItems = [];
  let totalAmount = 0;
  customerTransactions.forEach(function (lineItem) {
    let lineItemProduct = products.filter(function (product) {
      return product.sku_name == lineItem.sku;
    })[0];
    const qty = parseInt(lineItem.licenses);
    const price = parseFloat(lineItemProduct.price).toFixed(2);
    const amount = parseFloat(qty * price).toFixed(2);
    lineItems.push([lineItemProduct.sku_name, lineItemProduct.sku_description, '', qty, price, amount]);
    totalAmount += parseFloat(amount);
  });

  // Generates a random invoice number. You can replace with your own document ID method.
  const invoiceNumber = Math.floor(100000 + Math.random() * 900000);

  // Calulates dates.
  const todaysDate = new Date().toDateString()
  const dueDate = new Date(Date.now() + 1000 * 60 * 60 * 24 * DUE_DATE_NUM_DAYS).toDateString()

  // Sets values in the template.
  templateSheet.getRange('B10').setValue(customer.customer_name)
  templateSheet.getRange('B11').setValue(customer.address)
  templateSheet.getRange('F10').setValue(invoiceNumber)
  templateSheet.getRange('F12').setValue(todaysDate)
  templateSheet.getRange('F14').setValue(dueDate)
  templateSheet.getRange(18, 2, lineItems.length, 6).setValues(lineItems);

  // Cleans up and creates PDF.
  SpreadsheetApp.flush();
  Utilities.sleep(500); // Using to offset any potential latency in creating .pdf
  const pdf = createPDF(ssId, templateSheet, `Invoice#${invoiceNumber}-${customer.customer_name}`);
  return [invoiceNumber, todaysDate, customer.customer_name, customer.email, '', totalAmount, dueDate, pdf.getUrl(), 'No'];
}

/**
* Resets the template sheet by clearing out customer data.
* You use this to prepare for the next iteration or to view blank
* the template for design.
* 
* Called by createInvoiceForCustomer() or by the user via custom menu item.
*/
function clearTemplateSheet() {

  const ss = SpreadsheetApp.getActiveSpreadsheet();
  const templateSheet = ss.getSheetByName(INVOICE_TEMPLATE_SHEET_NAME);
  // Clears existing data from the template.
  const rngClear = templateSheet.getRangeList(['B10:B11', 'F10', 'F12', 'F14']).getRanges()
  rngClear.forEach(function (cell) {
    cell.clearContent();
  });
  // This sample only accounts for six rows of data 'B18:G24'. You can extend or make dynamic as necessary.
  templateSheet.getRange(18, 2, 7, 6).clearContent();
}

/**
 * Creates a PDF for the customer given sheet.
 * @param {string} ssId - Id of the Google Spreadsheet
 * @param {object} sheet - Sheet to be converted as PDF
 * @param {string} pdfName - File name of the PDF being created
 * @return {file object} PDF file as a blob
 */
function createPDF(ssId, sheet, pdfName) {
  const fr = 0, fc = 0, lc = 9, lr = 27;
  const url = "https://docs.google.com/spreadsheets/d/" + ssId + "/export" +
    "?format=pdf&" +
    "size=7&" +
    "fzr=true&" +
    "portrait=true&" +
    "fitw=true&" +
    "gridlines=false&" +
    "printtitle=false&" +
    "top_margin=0.5&" +
    "bottom_margin=0.25&" +
    "left_margin=0.5&" +
    "right_margin=0.5&" +
    "sheetnames=false&" +
    "pagenum=UNDEFINED&" +
    "attachment=true&" +
    "gid=" + sheet.getSheetId() + '&' +
    "r1=" + fr + "&c1=" + fc + "&r2=" + lr + "&c2=" + lc;

  const params = { method: "GET", headers: { "authorization": "Bearer " + ScriptApp.getOAuthToken() } };
  const blob = UrlFetchApp.fetch(url, params).getBlob().setName(pdfName + '.pdf');

  // Gets the folder in Drive where the PDFs are stored.
  const folder = getFolderByName_(OUTPUT_FOLDER_NAME);

  const pdfFile = folder.createFile(blob);
  return pdfFile;
}


/**
 * Sends emails with PDF as an attachment.
 * Checks/Sets 'Email Sent' column to 'Yes' to avoid resending.
 * 
 * Called by user via custom menu item.
 */
function sendEmails() {
  const ss = SpreadsheetApp.getActiveSpreadsheet();
  const invoicesSheet = ss.getSheetByName(INVOICES_SHEET_NAME);
  const invoicesData = invoicesSheet.getRange(1, 1, invoicesSheet.getLastRow(), invoicesSheet.getLastColumn()).getValues();
  const keysI = invoicesData.splice(0, 1)[0];
  const invoices = getObjects(invoicesData, createObjectKeys(keysI));
  ss.toast('Emailing Invoices', APP_TITLE, 1);
  invoices.forEach(function (invoice, index) {

    if (invoice.email_sent != 'Yes') {
      ss.toast(`Emailing Invoice for ${invoice.customer}`, APP_TITLE, 1);

      const fileId = invoice.invoice_link.match(/[-\w]{25,}(?!.*[-\w]{25,})/)
      const attachment = DriveApp.getFileById(fileId);

      let recipient = invoice.email;
      if (EMAIL_OVERRIDE) {
        recipient = EMAIL_ADDRESS_OVERRIDE
      }

      GmailApp.sendEmail(recipient, EMAIL_SUBJECT, EMAIL_BODY, {
        attachments: [attachment.getAs(MimeType.PDF)],
        name: APP_TITLE
      });
      invoicesSheet.getRange(index + 2, 9).setValue('Yes');
    }
  });
}

/**
 * Helper function that turns sheet data range into an object. 
 * 
 * @param {SpreadsheetApp.Sheet} sheet - Sheet to process
 * Return {object} of a sheet's datarange as an object 
 */
function dataRangeToObject(sheet) {
  const dataRange = sheet.getRange(1, 1, sheet.getLastRow(), sheet.getLastColumn()).getValues();
  const keys = dataRange.splice(0, 1)[0];
  return getObjects(dataRange, createObjectKeys(keys));
}

/**
 * Utility function for mapping sheet data to objects.
 */
function getObjects(data, keys) {
  let objects = [];
  for (let i = 0; i < data.length; ++i) {
    let object = {};
    let hasData = false;
    for (let j = 0; j < data[i].length; ++j) {
      let cellData = data[i][j];
      if (isCellEmpty(cellData)) {
        continue;
      }
      object[keys[j]] = cellData;
      hasData = true;
    }
    if (hasData) {
      objects.push(object);
    }
  }
  return objects;
}
// Creates object keys for column headers.
function createObjectKeys(keys) {
  return keys.map(function (key) {
    return key.replace(/\W+/g, '_').toLowerCase();
  });
}
// Returns true if the cell where cellData was read from is empty.
function isCellEmpty(cellData) {
  return typeof (cellData) == "string" && cellData == "";
}

solutions/automations/generate-pdfs/Menu.js
/**
 * Copyright 2022 Google LLC
 *
 * Licensed under the Apache License, Version 2.0 (the "License");
 * you may not use this file except in compliance with the License.
 * You may obtain a copy of the License at
 *
 *      http://www.apache.org/licenses/LICENSE-2.0
 *
 * Unless required by applicable law or agreed to in writing, software
 * distributed under the License is distributed on an "AS IS" BASIS,
 * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
 * See the License for the specific language governing permissions and
 * limitations under the License.
 */

/**
 * @OnlyCurrentDoc
 *
 * The above comment specifies that this automation will only
 * attempt to read or modify the spreadsheet this script is bound to.
 * The authorization request message presented to users reflects the
 * limited scope.
 */

/**
 * Creates a custom menu in the Google Sheets UI when the document is opened.
 *
 * @param {object} e The event parameter for a simple onOpen trigger.
 */
function onOpen(e) {

const menu = SpreadsheetApp.getUi().createMenu(APP_TITLE)
  menu
    .addItem('Process invoices', 'processDocuments')
    .addItem('Send emails', 'sendEmails')
    .addSeparator()
    .addItem('Reset template', 'clearTemplateSheet')
    .addToUi();
}

Utilities.gs

solutions/automations/generate-pdfs/Utilities.js
/**
 * Copyright 2022 Google LLC
 *
 * Licensed under the Apache License, Version 2.0 (the "License");
 * you may not use this file except in compliance with the License.
 * You may obtain a copy of the License at
 *
 *      http://www.apache.org/licenses/LICENSE-2.0
 *
 * Unless required by applicable law or agreed to in writing, software
 * distributed under the License is distributed on an "AS IS" BASIS,
 * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
 * See the License for the specific language governing permissions and
 * limitations under the License.
 */

/**
 * Returns a Google Drive folder in the same location 
 * in Drive where the spreadsheet is located. First, it checks if the folder
 * already exists and returns that folder. If the folder doesn't already
 * exist, the script creates a new one. The folder's name is set by the
 * "OUTPUT_FOLDER_NAME" variable from the Code.gs file.
 *
 * @param {string} folderName - Name of the Drive folder. 
 * @return {object} Google Drive Folder
 */
function getFolderByName_(folderName) {

  // Gets the Drive Folder of where the current spreadsheet is located.
  const ssId = SpreadsheetApp.getActiveSpreadsheet().getId();
  const parentFolder = DriveApp.getFileById(ssId).getParents().next();

  // Iterates the subfolders to check if the PDF folder already exists.
  const subFolders = parentFolder.getFolders();
  while (subFolders.hasNext()) {
    let folder = subFolders.next();

    // Returns the existing folder if found.
    if (folder.getName() === folderName) {
      return folder;
    }
  }
  // Creates a new folder if one does not already exist.
  return parentFolder.createFolder(folderName)
    .setDescription(`Created by ${APP_TITLE} application to store PDF output files`);
}

/**
 * Test function to run getFolderByName_.
 * @prints a Google Drive FolderId.
 */
function test_getFolderByName() {

  // Gets the PDF folder in Drive.
  const folder = getFolderByName_(OUTPUT_FOLDER_NAME);

  console.log(`Name: ${folder.getName()}\rID: ${folder.getId()}\rDescription: ${folder.getDescription()}`)
  // To automatically delete test folder, uncomment the following code:
  // folder.setTrashed(true);
}

貢獻者

這個範例是由 Google 維護,並由 Google 開發人員專家提供協助。

後續步驟