/**
* Add a pivot table.
* @param {string} spreadsheetId The spreadsheet ID to add the pivot table to.
* @param {string} pivotSourceDataSheetId The sheet ID to get the data from.
* @param {string} destinationSheetId The sheet ID to add the pivot table to.
* @see https://developers.google.com/sheets/api/reference/rest/v4/spreadsheets/batchUpdate
*/
function addPivotTable(
spreadsheetId = yourspreadsheetId,
pivotSourceDataSheetId = yourpivotSourceDataSheetId,
destinationSheetId = yourdestinationSheetId,
) {
const requests = [
{
updateCells: {
rows: {
values: [
{
pivotTable: {
source: {
sheetId: pivotSourceDataSheetId,
startRowIndex: 0,
startColumnIndex: 0,
endRowIndex: 20,
endColumnIndex: 7,
},
rows: [
{
sourceColumnOffset: 0,
showTotals: true,
sortOrder: "ASCENDING",
valueBucket: {
buckets: [
{
stringValue: "West",
},
],
},
},
{
sourceColumnOffset: 1,
showTotals: true,
sortOrder: "DESCENDING",
valueBucket: {},
},
],
columns: [
{
sourceColumnOffset: 4,
sortOrder: "ASCENDING",
showTotals: true,
valueBucket: {},
},
],
values: [
{
summarizeFunction: "SUM",
sourceColumnOffset: 3,
},
],
valueLayout: "HORIZONTAL",
},
},
],
},
start: {
sheetId: destinationSheetId,
rowIndex: 49,
columnIndex: 0,
},
fields: "pivotTable",
},
},
];
try {
const response = Sheets.Spreadsheets.batchUpdate(
{ requests: requests },
spreadsheetId,
);
// The Pivot table will appear anchored to cell A50 of the destination sheet.
} catch (e) {
// TODO (developer) - Handle exception
console.log("Failed with error %s", e.message);
}
}