Google Apps 脚本可让您在 Google 表格中实现各种新颖有趣的功能。您可以使用 Apps 脚本向 Google 表格添加自定义菜单、对话框和边栏。您还可以为 Google 表格编写自定义函数,以及将 Google 表格与其他 Google 服务(例如日历、云端硬盘和 Gmail)集成。
大多数为 Google 表格设计的脚本都会处理数组,以便与电子表格中的单元格、行和列进行互动。如果您不熟悉 JavaScript 中的数组,Codecademy 提供了一个出色的数组训练模块。(请注意,本课程并非由 Google 开发,也与 Google 无关。)
如需快速了解如何将 Apps 脚本与 Google 表格搭配使用,请参阅有关宏、菜单和自定义函数的 5 分钟快速入门指南。
开始使用
Apps 脚本包含一些特殊 API,可让您以编程方式创建、读取和修改 Google 表格。Apps 脚本可以通过两种广泛的方式与 Google 表格互动:任何脚本都可以创建或修改电子表格,前提是脚本的用户拥有对该电子表格的相应权限;脚本还可以绑定到电子表格,这会赋予脚本更改用户界面或在电子表格打开时做出响应的特殊能力。如需创建绑定脚本,请在 Google 表格中选择扩展>Apps 脚本。
电子表格服务将 Google 表格视为网格,并使用二维数组进行操作。如需从电子表格中检索数据,您必须获得对存储数据的电子表格的访问权限,获取电子表格中包含数据的范围,然后获取相应单元格的值。Apps 脚本通过读取电子表格中的结构化数据并为其创建 JavaScript 对象,来简化对数据的访问。
您可以通过添加自定义菜单、对话框和边栏来自定义 Google 表格。如需了解创建菜单的基础知识,请参阅菜单指南。如需了解如何自定义对话框的内容,请参阅 HTML 服务指南。
您还可以将脚本函数附加到电子表格中的图片或绘图;当用户点击图片或绘图时,该函数将执行。如需了解详情,请参阅 Google 表格中的图片和绘图。
如果您打算将自定义界面作为插件的一部分发布,请遵循样式指南,以确保与 Google 表格编辑器的样式和布局保持一致。
连接到 Google 表单
借助 Apps 脚本,您可以通过 Forms 和 Spreadsheet 服务将 Google 表单与 Google 表格相关联。此功能可根据电子表格中的数据自动创建 Google 表单。借助 Apps 脚本,您还可以使用触发器(例如 onFormSubmit)在用户回复表单后执行特定操作。如需详细了解如何将 Google 表格关联到 Google 表单,请尝试管理 Google 表单的回答 5 分钟快速入门教程。
借助 Apps 脚本,您可以访问 Google 表格中现有的数据验证规则,也可以创建新规则。例如,以下示例展示了如何设置数据验证规则,以仅允许在单元格中输入介于 1 到 100 之间的数字。
functionvalidateMySpreadsheet(){//SetaruleforthecellB4tobeanumberbetween1and100.varcell=SpreadsheetApp.getActive().getRange('B4');varrule=SpreadsheetApp.newDataValidation().requireNumberBetween(1,100).setAllowInvalid(false).setHelpText('Number must be between 1 and 100.').build();cell.setDataValidation(rule);}
[[["易于理解","easyToUnderstand","thumb-up"],["解决了我的问题","solvedMyProblem","thumb-up"],["其他","otherUp","thumb-up"]],[["没有我需要的信息","missingTheInformationINeed","thumb-down"],["太复杂/步骤太多","tooComplicatedTooManySteps","thumb-down"],["内容需要更新","outOfDate","thumb-down"],["翻译问题","translationIssue","thumb-down"],["示例/代码问题","samplesCodeIssue","thumb-down"],["其他","otherDown","thumb-down"]],["最后更新时间 (UTC):2025-08-31。"],[[["\u003cp\u003eGoogle Apps Script allows you to extend Google Sheets functionality by creating custom menus, dialogs, sidebars, and functions, as well as integrating with other Google services.\u003c/p\u003e\n"],["\u003cp\u003eApps Script interacts with Google Sheets data primarily through arrays, enabling you to read, write, and manipulate spreadsheet content programmatically.\u003c/p\u003e\n"],["\u003cp\u003eYou can customize the user interface of Google Sheets with Apps Script by adding custom menus, dialogs, and sidebars, and even connect it to Google Forms for automated workflows.\u003c/p\u003e\n"],["\u003cp\u003eApps Script provides functionalities to format cells, validate data, create charts, and define custom functions within your spreadsheets.\u003c/p\u003e\n"],["\u003cp\u003eGoogle Apps Script projects can be packaged as add-ons and published for others to use, and triggers can be set to automatically execute scripts based on specific events.\u003c/p\u003e\n"]]],[],null,["# Extending Google Sheets\n\nGoogle Apps Script lets you do new and cool things with Google Sheets. You can\nuse Apps Script to add [custom menus](/apps-script/guides/menus),\n[dialogs, and sidebars](/apps-script/guides/dialogs) to Google Sheets. It also\nlets you write [custom functions](/apps-script/guides/sheets/functions) for\nSheets, as well as integrate Sheets with other\n[Google services](/apps-script/guides/services) like Calendar, Drive, and\nGmail.\n\nMost scripts designed for Google Sheets manipulate arrays to\ninteract with the cells, rows, and columns in a spreadsheet. If you're not\nfamiliar with arrays in JavaScript, Codecademy offers a\n[great training module for arrays](https://www.codecademy.com/learn/introduction-to-javascript/modules/learn-javascript-arrays).\n(Note that this course wasn't developed by and isn't associated with Google.)\n\nFor a quick introduction to using Apps Script with Google Sheets, see the\n5-minute quickstart guide for\n[Macros, Menus, and Custom Functions](/apps-script/quickstart/macros).\n\nGet started\n-----------\n\nApps Script includes special APIs to let you programmatically create, read, and\nedit Google Sheets. Apps Script can interact with Google Sheets in two broad\nways: any script can create or modify a spreadsheet if the script's user has\nappropriate permissions for the spreadsheet, and a script can also be\n[bound](/apps-script/guides/bound) to a spreadsheet, which\ngives the script special abilities to alter the user interface or respond when\nthe spreadsheet is opened. To create a bound script, select\n**Extensions** \\\u003e **Apps Script** from within\nGoogle Sheets.\n\nThe [Spreadsheet service](/apps-script/reference/spreadsheet) treats Google\nSheets as a grid, operating with two-dimensional arrays. To retrieve the data\nfrom the spreadsheet, you must get access to the spreadsheet where the data is\nstored, get the range in the spreadsheet that holds the data, and then get the\nvalues of the cells. Apps Script facilitates access to the data by reading\nstructured data in the spreadsheet and creating JavaScript objects for them.\n\n### Reading data\n\nSuppose you have a list of product names and product numbers that you store in\na spreadsheet, as shown in the image below.\n\nThe example below shows how to retrieve and log the product names and product\nnumbers. \n\n function logProductInfo() {\n var sheet = SpreadsheetApp.getActiveSheet();\n var data = sheet.getDataRange().getValues();\n for (var i = 0; i \u003c data.length; i++) {\n Logger.log('Product name: ' + data[i][0]);\n Logger.log('Product number: ' + data[i][1]);\n }\n }\n\n#### View logs\n\nTo view the data that has been logged, at the top of the script editor, click\n**Execution log**.\n\n### Writing data\n\nTo store data, such as a new product name and number to the\nspreadsheet, add the following code to the end of the script. \n\n function addProduct() {\n var sheet = SpreadsheetApp.getActiveSheet();\n sheet.appendRow(['Cotton Sweatshirt XL', 'css004']);\n }\n\nThe above code appends a new row at the bottom of the spreadsheet, with the\nvalues specified. If you run this function, you'll see a new row added to the\nspreadsheet.\n\nCustom menus and user interfaces\n--------------------------------\n\nYou can customize Google Sheets by adding custom menus, dialog boxes, and\nsidebars. To learn the basics of creating menus, see the\n[guide to menus](/apps-script/guides/menus). To learn about customizing the\ncontent of a dialog box, see the\n[guide to HTML service](/apps-script/guides/html#serve_html_as_a_google_docs_sheets_or_forms_user_interface).\n\nYou can also attach a script function to an image or drawing within a\nspreadsheet; the function will execute when a user clicks on the image or\ndrawing. To learn more, see [Images and Drawings in Google Sheets](/apps-script/guides/menus#clickable_images_and_drawings_in_google_sheets).\n\nIf you're planning to publish your custom interface as part of an\n[add-on](#add-ons_for_google_sheets), follow the\n[style guide](/workspace/add-ons/guides/editor-style) for consistency with the\nstyle and layout of the Google Sheets editor.\n\nConnecting to Google Forms\n--------------------------\n\nApps Script allows you to connect Google Forms with Google Sheets through\n[Forms](/apps-script/reference/forms) and\n[Spreadsheet](/apps-script/reference/spreadsheet) services. This feature\ncan automatically create a Google Form based on data in a spreadsheet.\nApps Script also enables you to use [triggers](#triggers), such as\n`onFormSubmit` to perform a specific action after a user responds to the form.\nTo learn more about connecting Google Sheets to Google Forms, try the [Managing\nResponses for Google Forms](/apps-script/quickstart/forms) 5-minute quickstart.\n\nFormatting\n----------\n\nThe [`Range`](/apps-script/reference/spreadsheet/range) class has methods like\n[`setBackground(color)`](/apps-script/reference/spreadsheet/range#setBackground(String))\nto access and modify the format of a cell or range of cells. The following\nexample shows how you can set the font style of a range: \n\n function formatMySpreadsheet() {\n // Set the font style of the cells in the range of B2:C2 to be italic.\n var ss = SpreadsheetApp.getActiveSpreadsheet();\n var sheet = ss.getSheets()[0];\n var cell = sheet.getRange('B2:C2');\n cell.setFontStyle('italic');\n }\n\nData validation\n---------------\n\nApps Script lets you access existing data-validation rules in Google Sheets\nor create new rules. For instance, the following sample shows how to set a\ndata-validation rule that allows only numbers between 1 and 100 on a cell. \n\n function validateMySpreadsheet() {\n // Set a rule for the cell B4 to be a number between 1 and 100.\n var cell = SpreadsheetApp.getActive().getRange('B4');\n var rule = SpreadsheetApp.newDataValidation()\n .requireNumberBetween(1, 100)\n .setAllowInvalid(false)\n .setHelpText('Number must be between 1 and 100.')\n .build();\n cell.setDataValidation(rule);\n }\n\nFor more details on working with data-validation rules, see\n[`SpreadsheetApp.newDataValidation()`](/apps-script/reference/spreadsheet/spreadsheet-app#newDataValidation()),\n[`DataValidationBuilder`](/apps-script/reference/spreadsheet/data-validation-builder),\nand [`Range.setDataValidation(rule)`](/apps-script/reference/spreadsheet/range#setDataValidation(DataValidation))\n\nCharts\n------\n\nApps Script lets you embed charts in a spreadsheet that represent the data in a\nspecific range. The following example generates an embedded bar chart, assuming\nyou have chartable data in cells `A1:B15`: \n\n function newChart() {\n // Generate a chart representing the data in the range of A1:B15.\n var ss = SpreadsheetApp.getActiveSpreadsheet();\n var sheet = ss.getSheets()[0];\n\n var chart = sheet.newChart()\n .setChartType(Charts.ChartType.BAR)\n .addRange(sheet.getRange('A1:B15'))\n .setPosition(5, 5, 0, 0)\n .build();\n\n sheet.insertChart(chart);\n }\n\nTo learn more about embedding a chart into your spreadsheet,\nsee [`EmbeddedChart`](/apps-script/reference/spreadsheet/embedded-chart) and\nspecific chart builders, such as\n[`EmbeddedPieChartBuilder`](/apps-script/reference/spreadsheet/embedded-pie-chart-builder).\n\nCustom functions in Google Sheets\n---------------------------------\n\nA [custom function](/apps-script/guides/sheets/functions) is similar to a\nbuilt-in spreadsheet function like `=SUM(A1:A5)` except that you define the\nfunctions's behavior with Apps Script. For example, you could create a custom\nfunction, `in2mm()`, that converts a value from inches to millimeters, then use\nthe formula in your spreadsheet by typing `=in2mm(A1)` or `=in2mm(10)` into a\ncell.\n\nTo learn more about custom functions, try the\n[Menus and Custom Functions](/apps-script/quickstart/custom-functions)\n5-minute quickstart, or take a look at the more in-depth\n[guide to custom functions](/apps-script/guides/sheets/functions).\n\nMacros\n------\n\nMacros are another way of executing Apps Script code from the Google Sheets UI.\nUnlike custom functions, you activate them with a keyboard shortcut or through\nthe Google Sheets menu. For more information, see\n[Google Sheets Macros](/apps-script/guides/sheets/macros).\n\nAdd-ons for Google Sheets\n-------------------------\n\n[Add-ons](/workspace/add-ons/overview) are specially packaged Apps Script\nprojects that run inside Google Sheets and can be installed\nfrom the Google Sheets add-on store. If you've developed a script for Google Sheets\nand want to share it with the world, Apps Script lets you\n[publish](/workspace/add-ons/how-tos/editor-publish-overview) your script as an\nadd-on so other users can install it from the add-on store.\n\nTriggers\n--------\n\nScripts that are [bound](/apps-script/guides/bound) to a Google Sheets file\ncan use [simple triggers](/apps-script/guides/triggers) like the functions\n`onOpen()` and `onEdit()` to respond automatically when a user who has edit\naccess to the spreadsheet opens or edits the spreadsheet.\n\nLike simple triggers,\n[installable triggers](/apps-script/guides/triggers/installable) let Google Sheets\nrun a function automatically when a certain event occurs. Installable\ntriggers, however, offer more flexibility than simple triggers and support\nthe following events: open, edit, change, form submit, and time-driven (clock)."]]