將巨集複製到其他試算表

程式設計層級:中級
時間長度:30 分鐘
專案類型:Google Workspace 外掛程式

目標

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

認識這項解決方案

手動將 Google 試算表巨集從某個試算表複製到另一個試算表,不僅相當耗時又容易出錯。此 Google Workspace 外掛程式會自動複製指令碼專案,並附加到使用者指定的試算表。雖然這個解決方案著重於試算表巨集,但是您可以藉此複製及分享任何容器繫結的指令碼。

分享巨集 Google Workspace 外掛程式的螢幕截圖

運作方式

這個指令碼會複製繫結至原始試算表的 Apps Script 專案,並建立繫結至使用者指定試算表的重複 Apps Script 專案。

Apps Script 服務

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

  • 網址擷取服務:連線至 AppsScript API,以複製來源專案並建立副本。
  • 指令碼服務:授權 Apps Script API,避免收到第二次授權提示。
  • 試算表服務:開啟目標試算表以新增複製的 Apps Script 專案。
  • 卡片服務:建立外掛程式的使用者介面。

必要條件

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

設定環境

在 Google Cloud 控制台中開啟 Cloud 專案

如果尚未開啟,請開啟要用於本範例的 Cloud 專案:

  1. 前往 Google Cloud 控制台的「選取專案」頁面。

    選取 Cloud 專案

  2. 選取要使用的 Google Cloud 專案。或是按一下「建立專案」,然後按照畫面上的指示操作。建立 Google Cloud 專案後,可能需要開啟專案的計費功能

開啟 Google Apps Script API

本快速入門導覽課程使用 Google Apps Script API。

使用 Google API 前,請先在 Google Cloud 專案中啟用這些 API。您可以在單一 Google Cloud 專案中啟用一或多個 API。
  • 在 Cloud 專案中開啟 Google Apps Script API。

    啟用 API

如要使用 Google Workspace 外掛程式,則須設定同意畫面。設定外掛程式的 OAuth 同意畫面會定義 Google 向使用者顯示的內容。

  1. 在 Google Cloud 控制台中,依序點選「選單」圖示 >「API 和服務」>「OAuth 同意畫面」

    前往 OAuth 同意畫面

  2. 在「使用者類型」部分,選取「內部」,然後按一下「建立」
  3. 填寫應用程式註冊表單,然後按一下「儲存並繼續」
  4. 目前,您可以略過新增範圍,然後按一下「儲存並繼續」。日後建立用於 Google Workspace 機構外部的應用程式時,必須將「使用者類型」變更為「外部」,然後新增應用程式所需的授權範圍。

  5. 查看您的應用程式註冊摘要。如要變更,請按一下「編輯」。如果應用程式註冊正確無誤,請按一下「Back to Dashboard」(返回資訊主頁)

設定指令碼

建立 Apps Script 專案

  1. 點選下列按鈕,開啟「Share a Mac」Apps Script 專案。
    開啟專案
  2. 按一下「Overview」
  3. 在總覽頁面上,按一下「建立副本」圖示 用於建立副本的圖示

複製 Cloud 專案編號

  1. 在 Google Cloud 控制台中,依序點選「選單」圖示 >「IAM 與管理」>「設定」

    前往「IAM 與管理員設定」

  2. 複製「Project number」欄位中的值。

設定 Apps Script 專案的 Cloud 專案

  1. 在複製的 Apps Script 專案中,按一下「Project Settings」圖示 專案設定圖示
  2. 按一下「Google Cloud Platform (GCP) 專案」下方的「變更專案」
  3. 在「GCP 專案編號」中貼上 Google Cloud 專案編號。
  4. 按一下「設定專案」

安裝測試部署作業

  1. 在複製的 Apps Script 專案中,按一下「Editor」圖示
  2. 開啟 UI.gs 檔案,然後按一下「Run」。出現提示時,請授權指令碼。
  3. 依序點選「部署」>「測試部署作業」
  4. 依序點選「安裝」>「完成」

取得巨集指令碼和試算表資訊

  1. 開啟具有巨集且您有權編輯的試算表。如要使用範例試算表,請製作範例巨集試算表
  2. 依序按一下「擴充功能」>「Apps Script」
  3. 在 Apps Script 專案中,按一下「專案設定」圖示 專案設定圖示
  4. 在指令碼 ID 下方,點選「複製」
  5. 在後續步驟中一併設定指令碼 ID。
  6. 開啟或新建要加入巨集的試算表。您必須具備編輯權限,才能編輯試算表。
  7. 複製試算表網址並在後續步驟中使用。

執行指令碼

確認資訊主頁設定中的 Google Apps Script API 已啟用。請按照下列步驟執行指令碼。

複製巨集

  1. 在試算表的右側欄中,開啟「Share Macro」外掛程式 用於建立副本的圖示
  2. 在「來源巨集」下方貼上指令碼 ID。
  3. 在「目標試算表」下方貼上試算表網址。
  4. 按一下「共用巨集」
  5. 按一下「授權存取」並授權外掛程式。
  6. 重複步驟 2 到 4。

開啟複製的巨集

  1. 開啟當初複製巨集的試算表 (如果尚未開啟)。
  2. 依序按一下「擴充功能」>「Apps Script」
  3. 如果沒看到複製的 Apps Script 專案,請確認資訊主頁設定中的 Google Apps Script API 已啟用,然後重複執行「複製巨集」下方所列的步驟。

檢查程式碼

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

查看原始碼

Code.gs

solutions/add-on/share-macro/Code.js
// To learn how to use this script, refer to the documentation:
// https://developers.devsite.corp.google.com/apps-script/add-ons/share-macro

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

/**
 * Uses Apps Script API to copy source Apps Script project 
 * to destination Google Spreadsheet container.
 * 
 * @param {string} sourceScriptId - Script ID of the source project.
 * @param {string} targetSpreadsheetUrl - URL if the target spreadsheet.
 * @return {Card[]} - Card indicating successful copy.
 */
function shareMacro_(sourceScriptId, targetSpreadsheetUrl) {

  // Gets the source project content using the Apps Script API.
  const sourceProject = APPS_SCRIPT_API.get(sourceScriptId);
  const sourceFiles = APPS_SCRIPT_API.getContent(sourceScriptId);

  // Opens the target spreadsheet and gets its ID.
  const parentSSId = SpreadsheetApp.openByUrl(targetSpreadsheetUrl).getId();

  // Creates an Apps Script project that's bound to the target spreadsheet.
  const targetProjectObj = APPS_SCRIPT_API.create(sourceProject.title, parentSSId);

  // Updates the Apps Script project with the source project content.
  APPS_SCRIPT_API.updateContent(targetProjectObj.scriptId, sourceFiles);

}

/**
 * Function that encapsulates Apps Script API project manipulation. 
*/
const APPS_SCRIPT_API = {
  accessToken: ScriptApp.getOAuthToken(),

  /* APPS_SCRIPT_API.get
   * Gets Apps Script source project.
   * @param {string} scriptId - Script ID of the source project.
   * @return {Object} - JSON representation of source project.
   */
  get: function (scriptId) {
    const url = ('https://script.googleapis.com/v1/projects/' + scriptId);
    const options = {
      "method": 'get',
      "headers": {
        "Authorization": "Bearer " + this.accessToken
      },
      "muteHttpExceptions": true,
    };
    const res = UrlFetchApp.fetch(url, options);
    if (res.getResponseCode() == 200) {
      return JSON.parse(res);
    } else {
      console.log('An error occurred gettting the project details');
      console.log(res.getResponseCode());
      console.log(res.getContentText());
      console.log(res);
      return false;
    }
  },

  /* APPS_SCRIPT_API.create
   * Creates new Apps Script project in the target spreadsheet.
   * @param {string} title - Name of Apps Script project.
   * @param {string} parentId - Internal ID of target spreadsheet.
   * @return {Object} - JSON representation completed project creation.
   */
  create: function (title, parentId) {
    const url = 'https://script.googleapis.com/v1/projects';
    const options = {
      "headers": {
        "Authorization": "Bearer " + this.accessToken,
        "Content-Type": "application/json"
      },
      "muteHttpExceptions": true,
      "method": "POST",
      "payload": { "title": title }
    }
    if (parentId) {
      options.payload.parentId = parentId;
    }
    options.payload = JSON.stringify(options.payload);
    let res = UrlFetchApp.fetch(url, options);
    if (res.getResponseCode() == 200) {
      res = JSON.parse(res);
      return res;
    } else {
      console.log("An error occurred while creating the project");
      console.log(res.getResponseCode());
      console.log(res.getContentText());
      console.log(res);
      return false;
    }
  },
   /* APPS_SCRIPT_API.getContent
   * Gets the content of the source Apps Script project.
   * @param {string} scriptId - Script ID of the source project.
   * @return {Object} - JSON representation of Apps Script project content.
   */
   getContent: function (scriptId) {
    const url = "https://script.googleapis.com/v1/projects/" + scriptId + "/content";
    const options = {
      "method": 'get',
      "headers": {
        "Authorization": "Bearer " + this.accessToken
      },
      "muteHttpExceptions": true,
    };
    let res = UrlFetchApp.fetch(url, options);
    if (res.getResponseCode() == 200) {
      res = JSON.parse(res);
      return res['files'];
    } else {
      console.log('An error occurred obtaining the content from the source script');
      console.log(res.getResponseCode());
      console.log(res.getContentText());
      console.log(res);
      return false;
    }
  },

  /* APPS_SCRIPT_API.updateContent
   * Updates (copies) content from source to target Apps Script project.
   * @param {string} scriptId - Script ID of the source project.
   * @param {Object} files - JSON representation of Apps Script project content.
   * @return {boolean} - Result status of the function.
   */
  updateContent: function (scriptId, files) {
    const url = "https://script.googleapis.com/v1/projects/" + scriptId + "/content";
    const options = {
      "method": 'put',
      "headers": {
        "Authorization": "Bearer " + this.accessToken
      },
      "contentType": "application/json",
      "payload": JSON.stringify({ "files": files }),
      "muteHttpExceptions": true,
    };
    let res = UrlFetchApp.fetch(url, options);
    if (res.getResponseCode() == 200) {
      return true;
    } else {
      console.log(`An error occurred updating content of script ${scriptId}`);
      console.log(res.getResponseCode());
      console.log(res.getContentText());
      console.log(res);
      return false;
    }
  }
}

UI.gs

solutions/add-on/share-macro/UI.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.
 */

// Change application logo here (and in manifest) as desired.
const ADDON_LOGO = 'https://www.gstatic.com/images/branding/product/2x/apps_script_48dp.png';

/**
 * Callback function for rendering the main card.
 * @return {CardService.Card} The card to show the user.
 */
function onHomepage(e) {
  return createSelectionCard(e);
}

/**
 * Builds the primary card interface used to collect user inputs.
 * 
 * @param {Object} e - Add-on event object.
 * @param {string} sourceScriptId - Script ID of the source project.
 * @param {string} targetSpreadsheetUrl - URL of the target spreadsheet.
 * @param {string[]} errors - Array of error messages. 
 * 
 * @return {CardService.Card} The card to show to the user for inputs.
 */
function createSelectionCard(e, sourceScriptId, targetSpreadsheetUrl, errors) {

  // Configures card header.
  let cardHeader = CardService.newCardHeader()
    .setTitle('Share macros with other spreadheets!')
    .setImageUrl(ADDON_LOGO)
    .setImageStyle(CardService.ImageStyle.SQUARE);

  // If form errors exist, configures section with error messages.
  let showErrors = false;

  if (errors && errors.length) {
    showErrors = true;
    let msg = errors.reduce((str, err) => `${str}• ${err}<br>`, '');
    msg = `<b>Form submission errors:</b><br><font color="#ba0000">${msg}</font>`;

    // Builds error message section.
    sectionErrors = CardService.newCardSection()
      .addWidget(CardService.newDecoratedText()
        .setText(msg)
        .setWrapText(true));
  }

  // Configures source project section.
  let sectionSource = CardService.newCardSection()
    .addWidget(CardService.newDecoratedText()
      .setText('<b>Source macro</b><br>The Apps Script project to copy'))

    .addWidget(CardService.newTextInput()
      .setFieldName('sourceScriptId')
      .setValue(sourceScriptId || '')
      .setTitle('Script ID of the source macro')
      .setHint('You must have at least edit permission for the source spreadsheet to access its script project'))

    .addWidget(CardService.newTextButton()
      .setText('Find the script ID')
      .setOpenLink(CardService.newOpenLink()
        .setUrl('https://developers.google.com/apps-script/api/samples/execute')
        .setOpenAs(CardService.OpenAs.FULL_SIZE)
        .setOnClose(CardService.OnClose.NOTHING)));

  // Configures target spreadsheet section.
  let sectionTarget = CardService.newCardSection()
    .addWidget(CardService.newDecoratedText()
      .setText('<b>Target spreadsheet</b>'))

    .addWidget(CardService.newTextInput()
      .setFieldName('targetSpreadsheetUrl')
      .setValue(targetSpreadsheetUrl || '')
      .setHint('You must have at least edit permission for the target spreadsheet')
      .setTitle('Target spreadsheet URL'));

  // Configures help section.
  let sectionHelp = CardService.newCardSection()
    .addWidget(CardService.newDecoratedText()
      .setText('<b><font color=#c80000>NOTE: </font></b>' +
        'The Apps Script API must be turned on.')
      .setWrapText(true))

    .addWidget(CardService.newTextButton()
      .setText('Turn on Apps Script API')
      .setOpenLink(CardService.newOpenLink()
        .setUrl('https://script.google.com/home/usersettings')
        .setOpenAs(CardService.OpenAs.FULL_SIZE)
        .setOnClose(CardService.OnClose.NOTHING)));

  // Configures card footer with action to copy the macro.
  var cardFooter = CardService.newFixedFooter()
    .setPrimaryButton(CardService.newTextButton()
      .setText('Share macro')
      .setOnClickAction(CardService.newAction()
        .setFunctionName('onClickFunction_')));

  // Begins building the card.
  let builder = CardService.newCardBuilder()
    .setHeader(cardHeader);

  // Adds error section if applicable.
  if (showErrors) {
    builder.addSection(sectionErrors)
  }

  // Adds final sections & footer.
  builder
    .addSection(sectionSource)
    .addSection(sectionTarget)
    .addSection(sectionHelp)
    .setFixedFooter(cardFooter);

  return builder.build();
}

/**
 * Action handler that validates user inputs and calls shareMacro_
 * function to copy Apps Script project to target spreadsheet.
 * 
 * @param {Object} e - Add-on event object.
 * 
 * @return {CardService.Card} Responds with either a success or error card.
 */
function onClickFunction_(e) {

  const sourceScriptId = e.formInput.sourceScriptId;
  const targetSpreadsheetUrl = e.formInput.targetSpreadsheetUrl;

  // Validates inputs for errors.
  const errors = [];

  // Pushes an error message if the Script ID parameter is missing.
  if (!sourceScriptId) {
    errors.push('Missing script ID');
  } else {

    // Gets the Apps Script project if the Script ID parameter is valid.
    const sourceProject = APPS_SCRIPT_API.get(sourceScriptId);
    if (!sourceProject) {
      // Pushes an error message if the Script ID parameter isn't valid.
      errors.push('Invalid script ID');
    }
  }

  // Pushes an error message if the spreadsheet URL is missing.
  if (!targetSpreadsheetUrl) {
    errors.push('Missing Spreadsheet URL');
  } else
    try {
      // Tests for valid spreadsheet URL to get the spreadsheet ID.
      const ssId = SpreadsheetApp.openByUrl(targetSpreadsheetUrl).getId();
    } catch (err) {
      // Pushes an error message if the spreadsheet URL parameter isn't valid.
      errors.push('Invalid spreadsheet URL');
    }

  if (errors && errors.length) {
    // Redisplays form if inputs are missing or invalid.
    return createSelectionCard(e, sourceScriptId, targetSpreadsheetUrl, errors);

  } else {
    // Calls shareMacro function to copy the project.
    shareMacro_(sourceScriptId, targetSpreadsheetUrl);

    // Creates a success card to display to users.
    return buildSuccessCard(e, targetSpreadsheetUrl);
  }
}

/**
 * Builds success card to inform user & let them open the spreadsheet.
 * 
 * @param {Object} e - Add-on event object.
 * @param {string} targetSpreadsheetUrl - URL of the target spreadsheet.
 * 
 * @return {CardService.Card} Returns success card.
 */function buildSuccessCard(e, targetSpreadsheetUrl) {

  // Configures card header.
  let cardHeader = CardService.newCardHeader()
    .setTitle('Share macros with other spreadsheets!')
    .setImageUrl(ADDON_LOGO)
    .setImageStyle(CardService.ImageStyle.SQUARE);

  // Configures card body section with success message and open button.
  let sectionBody1 = CardService.newCardSection()
    .addWidget(CardService.newTextParagraph()
      .setText('Sharing process is complete!'))
    .addWidget(CardService.newTextButton()
      .setText('Open spreadsheet')
      .setOpenLink(CardService.newOpenLink()
        .setUrl(targetSpreadsheetUrl)
        .setOpenAs(CardService.OpenAs.FULL_SIZE)
        .setOnClose(CardService.OnClose.RELOAD_ADD_ON)));
  let sectionBody2 = CardService.newCardSection()
    .addWidget(CardService.newTextParagraph()
      .setText('If you don\'t see the copied project in your target spreadsheet,' +
       ' make sure you turned on the Apps Script API in the Apps Script dashboard.'))
    .addWidget(CardService.newTextButton()
      .setText("Check API")
      .setOpenLink(CardService.newOpenLink()
        .setUrl('https://script.google.com/home/usersettings')
        .setOpenAs(CardService.OpenAs.FULL_SIZE)
        .setOnClose(CardService.OnClose.RELOAD_ADD_ON)));

  // Configures the card footer with action to start new process.
  let cardFooter = CardService.newFixedFooter()
    .setPrimaryButton(CardService.newTextButton()
      .setText('Share another')
      .setOnClickAction(CardService.newAction()
        .setFunctionName('onHomepage')));

  return builder = CardService.newCardBuilder()
    .setHeader(cardHeader)
    .addSection(sectionBody1)
    .addSection(sectionBody2)
    .setFixedFooter(cardFooter)
    .build();
 }

appsscript.json

solutions/add-on/share-macro/appsscript.json
{
  "timeZone": "America/Los_Angeles",
  "exceptionLogging": "STACKDRIVER",
  "runtimeVersion": "V8",
  "oauthScopes": [
    "https://www.googleapis.com/auth/spreadsheets",
    "https://www.googleapis.com/auth/script.external_request",
    "https://www.googleapis.com/auth/drive.readonly",
    "https://www.googleapis.com/auth/script.projects"
  ],
    "urlFetchWhitelist": [
    "https://script.googleapis.com/"
  ],
  "addOns": {
    "common": {
      "name": "Share Macro",
      "logoUrl": "https://www.gstatic.com/images/branding/product/2x/apps_script_48dp.png",
      "layoutProperties": {
        "primaryColor": "#188038",
        "secondaryColor": "#34a853"
      },
      "homepageTrigger": {
        "runFunction": "onHomepage"
      }
    },
    "sheets": {}
  }
}

貢獻者

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

後續步驟