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

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);
}

Amit Agarwal is a web geek, solo entrepreneur and loves making things on the Internet. Google recently awarded him the Google Developer Expert and Google Cloud Champion title for his work on Google Workspace and Google Apps Script.

Awards & Recognition

Google Developer Expert

Google Developer Expert

Google awarded us the Developer Expert title recogizing our work in Workspace

ProductHunt Golden Kitty

ProductHunt Golden Kitty

Our Gmail tool won the Lifehack of the Year award at ProductHunt Golden Kitty Awards

Microsoft MVP Alumni

Microsoft MVP Alumni

Microsoft awarded us the Most Valuable Professional title for 5 years in a row

Google Cloud Champion

Google Cloud Champion

Google awarded us the Champion Innovator award for technical expertise

Want to stay up to date?
Sign up for our email newsletter.

We will never send any spam emails. Promise 🫶🏻