使用 Gmail 和 Google 試算表建立合併郵件

程式設計層級:新手
時間長度:10 分鐘
專案類型:透過自訂選單自動執行自動化動作

想透過視訊學習嗎?
Google Workspace 開發人員頻道提供許多實用提示、秘訣和最新功能的影片。

目標

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

認識這項解決方案

使用 Google 試算表的資料自動填入電子郵件範本。這些電子郵件會從您的 Gmail 帳戶傳送,方便您回覆收件者的回覆。

重要事項:這個郵件合併範例必須遵守 Google 服務配額說明的電子郵件限制。

郵件合併範例

運作方式

您會建立一個 Gmail 草稿範本,其中的預留位置會對應至試算表中的資料。工作表中的每個資料欄標頭都代表一個預留位置標記。該指令碼會從試算表將每個預留位置的資訊傳送至電子郵件草稿中對應預留位置標記的位置。

Apps Script 服務

這項解決方案會使用以下服務:

必要條件

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

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

設定指令碼

建立 Apps Script 專案

  1. 按一下下列按鈕,建立 Gmail/試算表郵件合併範例試算表的副本。這個解決方案的 Apps Script 專案已附加至試算表。
    建立副本
  2. 在複製的試算表中,將「Recipients」(收件者) 欄更新為您要在郵件合併中使用的電子郵件地址。
  3. (選用) 新增、編輯或移除資料欄,自訂您要加入電子郵件範本中的資料。

如果您變更「Recipient」或「Email Sent」資料欄的名稱,必須更新 Apps Script 專案中的對應程式碼。依序點選「Extensions」>「Apps Script」,即可從試算表開啟 Apps Script 專案。

建立電子郵件範本

  1. 在 Gmail 帳戶中建立電子郵件草稿。如要在電子郵件中加入試算表的資料,請使用以大括號括住的資料欄名稱對應的預留位置,例如 {{First name}}
    • 如果您格式化電子郵件中的文字,也必須設定預留位置括號的格式。
    • 預留位置會區分大小寫,而且必須與欄標題完全相符。
  2. 複製電子郵件草稿的主旨行。

執行指令碼

  1. 在試算表中,依序按一下「郵件合併」>「傳送電子郵件」。您可能需要重新整理頁面,才能看到這個自訂選單。
  2. 出現提示訊息時,請授權指令碼。如果 OAuth 同意畫面顯示警告,請依序選取「Advanced」>「Go to {Project Name} (unsafe)」繼續操作。

  3. 再次依序點選「郵件合併」>「傳送電子郵件」

  4. 貼上電子郵件範本主旨行,然後按一下「確定」

如果您對工作表套用篩選器,指令碼仍會傳送電子郵件給篩選後的參與者,但不會新增時間戳記。

檢查程式碼

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

查看原始碼

Code.gs

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

/*
Copyright 2022 Martin Hawksey

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.
*/

/**
 * @OnlyCurrentDoc
*/

/**
 * Change these to match the column names you are using for email 
 * recipient addresses and email sent column.
*/
const RECIPIENT_COL  = "Recipient";
const EMAIL_SENT_COL = "Email Sent";

/** 
 * Creates the menu item "Mail Merge" for user to run scripts on drop-down.
 */
function onOpen() {
  const ui = SpreadsheetApp.getUi();
  ui.createMenu('Mail Merge')
      .addItem('Send Emails', 'sendEmails')
      .addToUi();
}

/**
 * Sends emails from sheet data.
 * @param {string} subjectLine (optional) for the email draft message
 * @param {Sheet} sheet to read data from
*/
function sendEmails(subjectLine, sheet=SpreadsheetApp.getActiveSheet()) {
  // option to skip browser prompt if you want to use this code in other projects
  if (!subjectLine){
    subjectLine = Browser.inputBox("Mail Merge", 
                                      "Type or copy/paste the subject line of the Gmail " +
                                      "draft message you would like to mail merge with:",
                                      Browser.Buttons.OK_CANCEL);

    if (subjectLine === "cancel" || subjectLine == ""){ 
    // If no subject line, finishes up
    return;
    }
  }

  // Gets the draft Gmail message to use as a template
  const emailTemplate = getGmailTemplateFromDrafts_(subjectLine);

  // Gets the data from the passed sheet
  const dataRange = sheet.getDataRange();
  // Fetches displayed values for each row in the Range HT Andrew Roberts 
  // https://mashe.hawksey.info/2020/04/a-bulk-email-mail-merge-with-gmail-and-google-sheets-solution-evolution-using-v8/#comment-187490
  // @see https://developers.google.com/apps-script/reference/spreadsheet/range#getdisplayvalues
  const data = dataRange.getDisplayValues();

  // Assumes row 1 contains our column headings
  const heads = data.shift(); 

  // Gets the index of the column named 'Email Status' (Assumes header names are unique)
  // @see http://ramblings.mcpher.com/Home/excelquirks/gooscript/arrayfunctions
  const emailSentColIdx = heads.indexOf(EMAIL_SENT_COL);

  // Converts 2d array into an object array
  // See https://stackoverflow.com/a/22917499/1027723
  // For a pretty version, see https://mashe.hawksey.info/?p=17869/#comment-184945
  const obj = data.map(r => (heads.reduce((o, k, i) => (o[k] = r[i] || '', o), {})));

  // Creates an array to record sent emails
  const out = [];

  // Loops through all the rows of data
  obj.forEach(function(row, rowIdx){
    // Only sends emails if email_sent cell is blank and not hidden by a filter
    if (row[EMAIL_SENT_COL] == ''){
      try {
        const msgObj = fillInTemplateFromObject_(emailTemplate.message, row);

        // See https://developers.google.com/apps-script/reference/gmail/gmail-app#sendEmail(String,String,String,Object)
        // If you need to send emails with unicode/emoji characters change GmailApp for MailApp
        // Uncomment advanced parameters as needed (see docs for limitations)
        GmailApp.sendEmail(row[RECIPIENT_COL], msgObj.subject, msgObj.text, {
          htmlBody: msgObj.html,
          // bcc: 'a.bcc@email.com',
          // cc: 'a.cc@email.com',
          // from: 'an.alias@email.com',
          // name: 'name of the sender',
          // replyTo: 'a.reply@email.com',
          // noReply: true, // if the email should be sent from a generic no-reply email address (not available to gmail.com users)
          attachments: emailTemplate.attachments,
          inlineImages: emailTemplate.inlineImages
        });
        // Edits cell to record email sent date
        out.push([new Date()]);
      } catch(e) {
        // modify cell to record error
        out.push([e.message]);
      }
    } else {
      out.push([row[EMAIL_SENT_COL]]);
    }
  });

  // Updates the sheet with new data
  sheet.getRange(2, emailSentColIdx+1, out.length).setValues(out);

  /**
   * Get a Gmail draft message by matching the subject line.
   * @param {string} subject_line to search for draft message
   * @return {object} containing the subject, plain and html message body and attachments
  */
  function getGmailTemplateFromDrafts_(subject_line){
    try {
      // get drafts
      const drafts = GmailApp.getDrafts();
      // filter the drafts that match subject line
      const draft = drafts.filter(subjectFilter_(subject_line))[0];
      // get the message object
      const msg = draft.getMessage();

      // Handles inline images and attachments so they can be included in the merge
      // Based on https://stackoverflow.com/a/65813881/1027723
      // Gets all attachments and inline image attachments
      const allInlineImages = draft.getMessage().getAttachments({includeInlineImages: true,includeAttachments:false});
      const attachments = draft.getMessage().getAttachments({includeInlineImages: false});
      const htmlBody = msg.getBody(); 

      // Creates an inline image object with the image name as key 
      // (can't rely on image index as array based on insert order)
      const img_obj = allInlineImages.reduce((obj, i) => (obj[i.getName()] = i, obj) ,{});

      //Regexp searches for all img string positions with cid
      const imgexp = RegExp('<img.*?src="cid:(.*?)".*?alt="(.*?)"[^\>]+>', 'g');
      const matches = [...htmlBody.matchAll(imgexp)];

      //Initiates the allInlineImages object
      const inlineImagesObj = {};
      // built an inlineImagesObj from inline image matches
      matches.forEach(match => inlineImagesObj[match[1]] = img_obj[match[2]]);

      return {message: {subject: subject_line, text: msg.getPlainBody(), html:htmlBody}, 
              attachments: attachments, inlineImages: inlineImagesObj };
    } catch(e) {
      throw new Error("Oops - can't find Gmail draft");
    }

    /**
     * Filter draft objects with the matching subject linemessage by matching the subject line.
     * @param {string} subject_line to search for draft message
     * @return {object} GmailDraft object
    */
    function subjectFilter_(subject_line){
      return function(element) {
        if (element.getMessage().getSubject() === subject_line) {
          return element;
        }
      }
    }
  }

  /**
   * Fill template string with data object
   * @see https://stackoverflow.com/a/378000/1027723
   * @param {string} template string containing {{}} markers which are replaced with data
   * @param {object} data object used to replace {{}} markers
   * @return {object} message replaced with data
  */
  function fillInTemplateFromObject_(template, data) {
    // We have two templates one for plain text and the html body
    // Stringifing the object means we can do a global replace
    let template_string = JSON.stringify(template);

    // Token replacement
    template_string = template_string.replace(/{{[^{}]+}}/g, key => {
      return escapeData_(data[key.replace(/[{}]+/g, "")] || "");
    });
    return  JSON.parse(template_string);
  }

  /**
   * Escape cell data to make JSON safe
   * @see https://stackoverflow.com/a/9204218/1027723
   * @param {string} str to escape JSON special characters from
   * @return {string} escaped string
  */
  function escapeData_(str) {
    return str
      .replace(/[\\]/g, '\\\\')
      .replace(/[\"]/g, '\\\"')
      .replace(/[\/]/g, '\\/')
      .replace(/[\b]/g, '\\b')
      .replace(/[\f]/g, '\\f')
      .replace(/[\n]/g, '\\n')
      .replace(/[\r]/g, '\\r')
      .replace(/[\t]/g, '\\t');
  };
}

修改

您可以視需要編輯郵件合併自動化功能,數量不限。 以下幾頁是原始碼中的選擇性變更。

新增密件副本、副本、回覆或寄件者電子郵件參數

程式碼範例也包含許多其他參數 (目前會被加註註解),以便您控制接收電子郵件的帳戶名稱、回覆電子郵件地址,以及密件副本和副本電子郵件地址。

移除每個參數前方的正斜線 //,啟用要新增的參數。

以下範例顯示了可啟用大多數電子郵件參數的 sendEmails 函式摘錄:

GmailApp.sendEmail(row[RECIPIENT_COL], msgObj.subject, msgObj.text, {
         htmlBody: msgObj.html,
         bcc: 'bcc@example.com',
         cc: 'cc@example.com',
         from: 'from.alias@example.com',
         name: 'name of the sender',
         replyTo: 'reply@example.com',
        // noReply: true, // if the email should be sent from a generic no-reply email address (not available to gmail.com users)

在上述範例中,由於已設定 replyTo 參數,noReply 參數仍然遭到註解排除。

在電子郵件中加入萬國碼 (Unicode) 字元

如要在電子郵件中加入萬國碼 (Unicode) 字元 (例如表情符號),您必須將程式碼更新為使用郵件服務 (而非 Gmail 服務)。

在範例程式碼中,更新以下這一行:

GmailApp.sendEmail(row[RECIPIENT_COL], msgObj.subject, msgObj.text, {

將這一行替換成以下的程式碼:

MailApp.sendEmail(row[RECIPIENT_COL], msgObj.subject, msgObj.text, {

貢獻者

此範例是由愛丁堡期貨研究所 (Edinburgh Futures Institute) 的學習設計與技術主管 Martin Hawksey 、網誌作者和 Google 開發人員專家所製作。

這個範例由 Google 開發人員專家協助維護。

後續步驟