Menyalin makro ke spreadsheet lain

Tingkat coding: Menengah
Durasi: 30 menit
Jenis project: Add-on Google Workspace

Tujuan

  • Pahami fungsi solusi.
  • Pahami fungsi layanan Apps Script dalam solusi.
  • Siapkan lingkungan.
  • Siapkan skrip.
  • Jalankan skrip.

Tentang solusi ini

Menyalin makro Google Spreadsheet secara manual dari satu spreadsheet ke spreadsheet lain dapat memakan waktu dan rentan error. Add-on Google Workspace ini otomatis menyalin project skrip dan melampirkan skrip tersebut ke spreadsheet yang ditentukan pengguna. Meskipun solusi ini berfokus pada makro Spreadsheet, Anda dapat menggunakannya untuk menyalin dan membagikan skrip yang terikat penampung.

Screenshot add-on Google Workspace Share Macro

Cara kerjanya

Skrip ini menyalin project Apps Script yang terikat dengan spreadsheet asli dan membuat project Apps Script duplikat yang terikat dengan spreadsheet yang ditentukan pengguna.

Layanan Apps Script

Solusi ini menggunakan layanan berikut:

  • Layanan URL-fetch–Terhubung ke Apps Script API untuk menyalin project sumber dan membuat salinan.
  • Layanan skrip–Memberi otorisasi pada Apps Script API untuk menghindari perintah otorisasi kedua.
  • Layanan spreadsheet–Membuka spreadsheet target untuk menambahkan project Apps Script yang disalin.
  • Layanan kartu–Membuat antarmuka pengguna add-on.

Prasyarat

Untuk menggunakan contoh ini, Anda memerlukan prasyarat berikut:

Menyiapkan lingkungan Anda

Buka project Cloud Anda di konsol Google Cloud

Jika belum terbuka, buka project Cloud yang ingin Anda gunakan untuk contoh ini:

  1. Di konsol Google Cloud, buka halaman Select a project.

    Memilih project Cloud

  2. Pilih project Google Cloud yang ingin Anda gunakan. Atau, klik Buat project dan ikuti petunjuk di layar. Jika membuat project Google Cloud, Anda mungkin perlu mengaktifkan penagihan untuk project tersebut.

Mengaktifkan Google Apps Script API

Panduan memulai ini menggunakan Google Apps Script API.

Sebelum menggunakan Google API, Anda harus mengaktifkannya di project Google Cloud. Anda dapat mengaktifkan satu atau beberapa API dalam satu project Google Cloud.

Add-on Google Workspace memerlukan konfigurasi layar izin. Mengonfigurasi layar izin OAuth add-on akan menentukan apa yang ditampilkan Google kepada pengguna.

  1. Di konsol Google Cloud, buka Menu > > Branding.

    Buka Branding

  2. Jika telah mengonfigurasi , Anda dapat mengonfigurasi setelan Layar Izin OAuth berikut di Branding, Audiens, dan Akses Data. Jika Anda melihat pesan yang bertuliskan not configured yet, klik Get Started:
    1. Di bagian Informasi Aplikasi, di Nama aplikasi, masukkan nama untuk aplikasi.
    2. Di Email dukungan pengguna, pilih alamat email dukungan yang dapat dihubungi pengguna jika mereka memiliki pertanyaan tentang izin mereka.
    3. Klik Berikutnya.
    4. Di bagian Audiens, pilih Internal.
    5. Klik Berikutnya.
    6. Di bagian Informasi Kontak, masukkan Alamat email tempat Anda dapat menerima notifikasi tentang perubahan apa pun pada project Anda.
    7. Klik Berikutnya.
    8. Di bagian Selesai, tinjau Kebijakan Data Pengguna Layanan Google API dan jika Anda setuju, pilih Saya setuju dengan Layanan Google API: Kebijakan Data Pengguna.
    9. Klik Lanjutkan.
    10. Klik Buat.
  3. Untuk saat ini, Anda dapat melewati penambahan cakupan. Di masa mendatang, saat membuat aplikasi untuk digunakan di luar organisasi Google Workspace, Anda harus mengubah Jenis pengguna menjadi Eksternal. Kemudian, tambahkan cakupan otorisasi yang diperlukan aplikasi Anda. Untuk mempelajari lebih lanjut, lihat panduan lengkap Mengonfigurasi izin OAuth.

Menyiapkan skrip

Membuat project Apps Script

  1. Klik tombol berikut untuk membuka project Apps Script Bagikan makro.
    Membuka project
  2. Klik Ringkasan .
  3. Di halaman ringkasan, klik Buat salinan Ikon untuk membuat salinan.

Menyalin nomor project Cloud

  1. Di konsol Google Cloud, buka Menu > IAM & Admin > Settings.

    Buka IAM & Admin Settings

  2. Di kolom Project number, salin nilainya.

Menetapkan project Cloud project Apps Script

  1. Di project Apps Script yang disalin, klik Project Settings Ikon untuk setelan project.
  2. Pada Google Cloud Platform (GCP) Project, klik Change project.
  3. Di GCP project number, tempel nomor project Google Cloud.
  4. Klik Set project.

Menginstal deployment pengujian

  1. Di project Apps Script yang disalin, klik Editor .
  2. Buka file UI.gs, lalu klik Jalankan. Jika diminta, izinkan skrip.
  3. Klik Deploy > Test deployments.
  4. Klik Instal > Selesai.

Mendapatkan informasi skrip makro dan spreadsheet

  1. Buka spreadsheet Spreadsheet yang memiliki makro dan Anda memiliki izin untuk mengeditnya. Untuk menggunakan contoh spreadsheet, buat salinan spreadsheet Contoh makro.
  2. Klik Ekstensi > Apps Script.
  3. Di project Apps Script, klik Project settings Ikon untuk setelan project.
  4. Di bagian ID skrip, klik Salin.
  5. Simpan ID skrip untuk digunakan di langkah berikutnya.
  6. Buka atau buat spreadsheet baru tempat Anda ingin menambahkan makro. Anda harus memiliki izin untuk mengedit spreadsheet.
  7. Salin URL spreadsheet dan sisihkan untuk digunakan di langkah berikutnya.

Jalankan skrip:

Pastikan Google Apps Script API diaktifkan di setelan dasbor Anda. Lakukan langkah-langkah di bagian berikut untuk menjalankan skrip Anda.

Menyalin makro

  1. Di Spreadsheet, di sidebar kanan, buka add-on Bagikan Makro Ikon untuk membuat salinan.
  2. Di bagian Source macro, tempel ID skrip.
  3. Di bagian Target spreadsheet, tempel URL spreadsheet.
  4. Klik Bagikan makro.
  5. Klik Authorize access dan beri otorisasi pada add-on.
  6. Ulangi langkah 2-4.

Membuka makro yang disalin

  1. Jika belum terbuka, buka spreadsheet tempat Anda menyalin makro.
  2. Klik Ekstensi > Apps Script.
  3. Jika Anda tidak melihat project Apps Script yang disalin, pastikan Google Apps Script API diaktifkan di setelan dasbor dan ulangi langkah-langkah yang tercantum di bagian Menyalin makro.

Meninjau kode

Untuk meninjau kode Apps Script untuk solusi ini, klik Lihat kode sumber di bawah:

Melihat kode sumber

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.
 */
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": {}
  }
}

Kontributor

Contoh ini dikelola oleh Google dengan bantuan Pakar Developer Google.

Langkah berikutnya