How to Update Multiple Cell Values in Google Sheets with Apps Script

H
Published in: Google Apps Script - Google Sheets

The SpreadsheetApp service of Google App Script offers the range.setValues() method to update a single cell or a range of cells inside a Google Spreadsheet. You cannot, however, write data to multiple non-consecutive cells in a Spreadsheet using the setValues() method.

The Google Spreadsheet API, available inside Apps Script project through Advanced Google Services, can update multiple cells in one execution. You can write values in single cells, rows, columns or even a 2d matrix of cells.

function updateGoogleSheet(spreadsheetId) {

  /* Written by Amit Agarwal */
  /* Web: ctrlq.org  Email: amit@labnol.org */

  var data = [
    {
      range: "Sheet1!A1",   // Update single cell
      values: [
        ["A1"]
      ]
    },
    {
      range: "Sheet1!B1:B3", // Update a column
      values: [
        ["B1"],["B2"],["B3"]
      ]
    },
    {
      range: "Sheet1!C1:E1", // Update a row
      values: [
        ["C1","D1","E1"]
      ]
    },
    {
      range: "Sheet1!F1:H2", // Update a 2d range
      values: [
        ["F1", "F2"],
        ["H1", "H2"]
      ]
    }];

  var resource = {
    valueInputOption: "USER_ENTERED",
    data: data
  };

  Sheets.Spreadsheets.Values.batchUpdate(resource, spreadsheetId);

}
Published in: Google Apps Script - Google Sheets

Looking for something? Find here!

Meet the Author

Web Geek, Tech Columnist
A
Amit Agarwal

Amit Agarwal is a Google Developer Expert in GSuite and Google Apps Script. He holds an engineering degree in Computer Science (I.I.T.) and is the first professional blogger in India. Read more on Lifehacker and YourStory

Get in touch