From db3fd080b1c63b131a9c1b421f8bc7ee07f0802e Mon Sep 17 00:00:00 2001 From: Bunnarin <161002845+Bunnarin@users.noreply.github.com> Date: Sat, 28 Jun 2025 20:58:14 +0700 Subject: [PATCH 1/7] added objectHash conversion --- sheetquery.gs | 281 ++++++++++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 281 insertions(+) create mode 100644 sheetquery.gs diff --git a/sheetquery.gs b/sheetquery.gs new file mode 100644 index 0000000..a99a9a8 --- /dev/null +++ b/sheetquery.gs @@ -0,0 +1,281 @@ +/** + * Run new sheet query + * + * @param {Spreadsheet} activeSpreadsheet Specific spreadsheet to use, or will use SpreadsheetApp.getActiveSpreadsheet() if undefined\ + * @return {SheetQueryBuilder} + */ +function sheetQuery(activeSpreadsheet) { + return new SheetQueryBuilder(activeSpreadsheet); +} + +/** + * SheetQueryBuilder class - Kind of an ORM for Google Sheets + */ +class SheetQueryBuilder { + constructor(activeSpreadsheet) { + this.columnNames = []; + this.headingRow = 1; + this._sheetHeadings = []; + this.activeSpreadsheet = activeSpreadsheet || SpreadsheetApp.getActiveSpreadsheet(); + } + select(columnNames) { + this.columnNames = Array.isArray(columnNames) ? columnNames : [columnNames]; + return this; + } + /** + * Name of spreadsheet to perform operations on + * + * @param {string} sheetName + * @param {number} headingRow + * @return {SheetQueryBuilder} + */ + from(sheetName, headingRow = 1) { + this.sheetName = sheetName; + this.headingRow = headingRow; + return this; + } + /** + * Apply a filtering function on rows in a spreadsheet before performing an operation on them + * + * @param {Function} fn + * @return {SheetQueryBuilder} + */ + where(fn) { + fn = (typeof fn == 'object') ? create_fn(fn, false) : fn; + this.whereFn = fn; + return this; + } + /** + * Get Sheet object that is referenced by the current query from() method + * + * @return {Sheet} + */ + getSheet() { + if (!this.sheetName) { + throw new Error('SheetQuery: No sheet selected. Select sheet with .from(sheetName) method'); + } + if (!this._sheet) { + this._sheet = this.activeSpreadsheet.getSheetByName(this.sheetName); + } + return this._sheet; + } + /** + * Get values in sheet from current query + where condition + */ + getValues() { + if (!this._sheetValues) { + const zh = this.headingRow - 1; + const sheet = this.getSheet(); + if (!sheet) + return []; + const rowValues = []; + const sheetValues = sheet.getDataRange().getValues(); + const numCols = sheetValues[0] ? sheetValues[0].length : 0; + const numRows = sheetValues.length; + const headings = (this._sheetHeadings = sheetValues[zh] || []); + for (let r = 0; r < numRows; r++) { + const obj = { __meta: { row: r + 1, cols: numCols } }; + for (let c = 0; c < numCols; c++) + obj[headings[c]] = sheetValues[r][c]; // @ts-ignore + rowValues.push(obj); + } + this._sheetValues = rowValues; + } + return this._sheetValues; + } + /** + * Return matching rows from sheet query + * + * @return {RowObject[]} + */ + getRows() { + const sheetValues = this.getValues(); + return this.whereFn ? sheetValues.filter(this.whereFn) : sheetValues; + } + /** + * Get array of headings in current sheet from() + * + * @return {string[]} + */ + getHeadings() { + if (!this._sheetHeadings || !this._sheetHeadings.length) { + const zh = this.headingRow - 1; + const sheet = this.getSheet(); + const numCols = sheet.getLastColumn(); + this._sheetHeadings = sheet.getSheetValues(1, 1, this.headingRow, numCols)[zh] || []; + this._sheetHeadings = this._sheetHeadings + .map((s) => (typeof s === 'string' ? s.trim() : '')) + .filter(Boolean); + } + return this._sheetHeadings || []; + } + /** + * Get all cells from a query + where condition + * @returns {any[]} + */ + getCells() { + const rows = this.getRows(); + const cellArray = []; + rows.forEach((row) => { + cellArray.push(this._sheet.getRange(row.__meta.row, 1, 1, row.__meta.cols)); + }); + return cellArray; + } + /** + * Get cells in sheet from current query + where condition and from specific header + * @param {string} key name of the column + * @param {Array} [keys] optionnal names of columns use to select more columns than one + * @returns {any[]} all the colum cells from the query's rows + */ + getCellsWithHeadings(key, headings) { + let rows = this.getRows(); + let indexColumn = 1; + const arrayCells = []; + for (const elem of this._sheetHeadings) { + if (elem == key) break; + indexColumn++; + } + rows.forEach((row) => { + arrayCells.push(this._sheet.getRange(row.__meta.row, indexColumn)); + }); + //If we got more thant one param + headings.forEach((col) => { + let indexColumn = 1; + for (const elem of this._sheetHeadings) { + if (elem == col) break; + indexColumn++; + } + rows.forEach((row) => { + arrayCells.push(this._sheet.getRange(row.__meta.row, indexColumn)); + }); + }); + return arrayCells; + } + /** + * Insert new rows into the spreadsheet + * Arrays of objects like { Heading: Value } + * + * @param {DictObject[]} newRows - Array of row objects to insert + * @return {SheetQueryBuilder} + */ + insertRows(newRows) { + const sheet = this.getSheet(); + const headings = this.getHeadings(); + newRows.forEach((row) => { + if (!row) { + return; + } + const rowValues = headings.map((heading) => { + const val = row[heading]; + return val === undefined || val === null || val === false ? '' : val; + }); + // appendRow() will throw if array is empty, so we check to prevent that + if (rowValues && rowValues.length !== 0) { + sheet.appendRow(rowValues); + } + }); + return this; + } + /** + * Delete matched rows from spreadsheet + * + * @return {SheetQueryBuilder} + */ + deleteRows() { + const rows = this.getRows(); + let i = 0; + rows.forEach((row) => { + const deleteRowRange = this._sheet.getRange(row.__meta.row - i, 1, 1, row.__meta.cols); + deleteRowRange.deleteCells(SpreadsheetApp.Dimension.ROWS); + i++; + }); + this.clearCache(); + return this; + } + /** + * Update matched rows in spreadsheet with provided function + * + * @param {UpdateFn} updateFn + * @return {SheetQueryBuilder} + */ + updateRows(updateFn) { + updateFn = (typeof updateFn == 'object') ? create_fn(updateFn, true) : updateFn; + const rows = this.getRows(); + for (let i = 0; i < rows.length; i++) { + this.updateRow(rows[i], updateFn); + } + this.clearCache(); + return this; + } + /** + * Update single row + */ + updateRow(row, updateFn) { + fn = (typeof updateFn == 'object') ? create_fn(fn, true) : fn; + const updatedRow = updateFn(row) || row; + const rowMeta = updatedRow.__meta; + const headings = this.getHeadings(); + delete updatedRow.__meta; + // Put new array data in order of headings in sheet + const arrayValues = headings.map((heading) => { + const val = updatedRow[heading]; + return val === undefined || val === null || val === false ? '' : val; + }); + const maxCols = Math.max(rowMeta.cols, arrayValues.length); + const updateRowRange = this.getSheet().getRange(rowMeta.row, 1, 1, maxCols); + const rangeData = updateRowRange.getValues()[0] || []; + // Map over old data in same index order to update it and ensure array length always matches + const newValues = rangeData.map((value, index) => { + const val = arrayValues[index]; + return val === undefined || val === null || val === false ? '' : val; + }); + updateRowRange.setValues([newValues]); + return this; + } + /** + * Clear cached values, headings, and flush all operations to sheet + * + * @return {SheetQueryBuilder} + */ + clearCache() { + this._sheetValues = null; + this._sheetHeadings = []; + SpreadsheetApp.flush(); + return this; + } +} + +// util +function create_fn(objHash, update = true) { + const operator = update ? '=' : '=='; + let functionBody = ''; + + // Iterate over the keys in the objHash + for (const key in objHash) { + // Ensure it's an own property, not inherited + if (Object.prototype.hasOwnProperty.call(objHash, key)) { + const value = objHash[key]; + + // Dynamically format the value correctly for inclusion in the function string. + // Strings need to be quoted, numbers/booleans/null/undefined can be inserted directly. + let formattedValue; + if (typeof value === 'string') { + // Escape quotes within the string to prevent breaking the generated code + formattedValue = JSON.stringify(value); + } else if (typeof value === 'object' && value !== null) { + // For objects/arrays, JSON.stringify is usually the safest way to embed them, + // but be aware of complexity for deeply nested objects. + formattedValue = JSON.stringify(value); + } else { + // For numbers, booleans, null, undefined + formattedValue = String(value); + } + + // Add the assignment statement to the function body + functionBody += ` row["${key}"] ${operator} ${formattedValue};\n`; + } + } + + // Construct the anonymous function using new Function(). + return new Function('row', functionBody); +} From afcbf75d5299174be2d2c1a2faa7195b4183047d Mon Sep 17 00:00:00 2001 From: Bunnarin <161002845+Bunnarin@users.noreply.github.com> Date: Sun, 29 Jun 2025 07:09:26 +0700 Subject: [PATCH 2/7] fixed issues --- appsscript.json | 7 +++++++ sheetquery.gs | 53 +++++++++++++++++++++++++++++++++++-------------- 2 files changed, 45 insertions(+), 15 deletions(-) create mode 100644 appsscript.json diff --git a/appsscript.json b/appsscript.json new file mode 100644 index 0000000..c03f344 --- /dev/null +++ b/appsscript.json @@ -0,0 +1,7 @@ +{ + "timeZone": "Asia/Bangkok", + "dependencies": { + }, + "exceptionLogging": "STACKDRIVER", + "runtimeVersion": "V8" +} \ No newline at end of file diff --git a/sheetquery.gs b/sheetquery.gs index a99a9a8..f401d57 100644 --- a/sheetquery.gs +++ b/sheetquery.gs @@ -41,7 +41,7 @@ class SheetQueryBuilder { * @return {SheetQueryBuilder} */ where(fn) { - fn = (typeof fn == 'object') ? create_fn(fn, false) : fn; + fn = (typeof fn == 'object') ? filter_fn(fn) : fn; this.whereFn = fn; return this; } @@ -84,11 +84,20 @@ class SheetQueryBuilder { return this._sheetValues; } /** - * Return matching rows from sheet query + * Return matching rows from sheet query excluding the header row * * @return {RowObject[]} */ getRows() { + const sheetValues = this.getValues().slice(1, -1); + return this.whereFn ? sheetValues.filter(this.whereFn) : sheetValues; + } + /** + * Return matching rows from sheet query including the header row + * + * @return {RowObject[]} + */ + getTable() { const sheetValues = this.getValues(); return this.whereFn ? sheetValues.filter(this.whereFn) : sheetValues; } @@ -114,7 +123,7 @@ class SheetQueryBuilder { * @returns {any[]} */ getCells() { - const rows = this.getRows(); + const rows = this.getTable(); const cellArray = []; rows.forEach((row) => { cellArray.push(this._sheet.getRange(row.__meta.row, 1, 1, row.__meta.cols)); @@ -128,7 +137,7 @@ class SheetQueryBuilder { * @returns {any[]} all the colum cells from the query's rows */ getCellsWithHeadings(key, headings) { - let rows = this.getRows(); + let rows = this.getTable(); let indexColumn = 1; const arrayCells = []; for (const elem of this._sheetHeadings) { @@ -182,7 +191,7 @@ class SheetQueryBuilder { * @return {SheetQueryBuilder} */ deleteRows() { - const rows = this.getRows(); + const rows = this.getTable(); let i = 0; rows.forEach((row) => { const deleteRowRange = this._sheet.getRange(row.__meta.row - i, 1, 1, row.__meta.cols); @@ -199,8 +208,8 @@ class SheetQueryBuilder { * @return {SheetQueryBuilder} */ updateRows(updateFn) { - updateFn = (typeof updateFn == 'object') ? create_fn(updateFn, true) : updateFn; - const rows = this.getRows(); + updateFn = (typeof updateFn == 'object') ? update_fn(updateFn) : updateFn; + const rows = this.getTable(); for (let i = 0; i < rows.length; i++) { this.updateRow(rows[i], updateFn); } @@ -211,7 +220,7 @@ class SheetQueryBuilder { * Update single row */ updateRow(row, updateFn) { - fn = (typeof updateFn == 'object') ? create_fn(fn, true) : fn; + updateFn = (typeof updateFn == 'object') ? update_fn(updateFn) : updateFn; const updatedRow = updateFn(row) || row; const rowMeta = updatedRow.__meta; const headings = this.getHeadings(); @@ -246,15 +255,14 @@ class SheetQueryBuilder { } // util -function create_fn(objHash, update = true) { - const operator = update ? '=' : '=='; +function update_fn(updateHash) { let functionBody = ''; - // Iterate over the keys in the objHash - for (const key in objHash) { + // Iterate over the keys in the updateHash + for (const key in updateHash) { // Ensure it's an own property, not inherited - if (Object.prototype.hasOwnProperty.call(objHash, key)) { - const value = objHash[key]; + if (Object.prototype.hasOwnProperty.call(updateHash, key)) { + const value = updateHash[key]; // Dynamically format the value correctly for inclusion in the function string. // Strings need to be quoted, numbers/booleans/null/undefined can be inserted directly. @@ -272,10 +280,25 @@ function create_fn(objHash, update = true) { } // Add the assignment statement to the function body - functionBody += ` row["${key}"] ${operator} ${formattedValue};\n`; + functionBody += ` row["${key}"] = ${formattedValue};\n`; } } // Construct the anonymous function using new Function(). return new Function('row', functionBody); } + +function filter_fn(filterHash) { + const conditions = []; + for (const key in filterHash) { + if (Object.prototype.hasOwnProperty.call(filterHash, key)) { + const value = filterHash[key]; + // Escape string values for proper inclusion in the function string + const escapedValue = typeof value === 'string' ? `'${value.replace(/'/g, "\\'")}'` : value; + conditions.push(`row["${key}"] === ${escapedValue}`); + } + } + + const functionBody = `return ${conditions.join(' && ')};`; + return new Function('row', functionBody); +} \ No newline at end of file From 1e1ee6409f33aa7aa695806e55ad4f805bbcc52b Mon Sep 17 00:00:00 2001 From: Bunnarin <161002845+Bunnarin@users.noreply.github.com> Date: Sun, 29 Jun 2025 19:38:28 +0700 Subject: [PATCH 3/7] added updateRow safe mode for when u want to not override existing formula. --- sheetquery.gs | 108 ++++++++++++++++++++++++++++++++++++++------------ 1 file changed, 83 insertions(+), 25 deletions(-) diff --git a/sheetquery.gs b/sheetquery.gs index f401d57..9827f0a 100644 --- a/sheetquery.gs +++ b/sheetquery.gs @@ -124,41 +124,35 @@ class SheetQueryBuilder { */ getCells() { const rows = this.getTable(); - const cellArray = []; + const returnValues = []; rows.forEach((row) => { - cellArray.push(this._sheet.getRange(row.__meta.row, 1, 1, row.__meta.cols)); + returnValues.push(this._sheet.getRange(row.__meta.row, 1, 1, row.__meta.cols).getValue()); }); - return cellArray; + return returnValues; } /** * Get cells in sheet from current query + where condition and from specific header * @param {string} key name of the column - * @param {Array} [keys] optionnal names of columns use to select more columns than one * @returns {any[]} all the colum cells from the query's rows */ - getCellsWithHeadings(key, headings) { - let rows = this.getTable(); + getAllByCol(key) { + const cells = []; + let rows = this.getRows(); let indexColumn = 1; - const arrayCells = []; + let found = false; for (const elem of this._sheetHeadings) { - if (elem == key) break; + if (elem == key) { + found = true; + break; + } indexColumn++; } + if (!found) + throw new Error(`no col found with ${key}`); rows.forEach((row) => { - arrayCells.push(this._sheet.getRange(row.__meta.row, indexColumn)); - }); - //If we got more thant one param - headings.forEach((col) => { - let indexColumn = 1; - for (const elem of this._sheetHeadings) { - if (elem == col) break; - indexColumn++; - } - rows.forEach((row) => { - arrayCells.push(this._sheet.getRange(row.__meta.row, indexColumn)); - }); + cells.push(this._sheet.getRange(row.__meta.row, indexColumn).getValue()); }); - return arrayCells; + return cells; } /** * Insert new rows into the spreadsheet @@ -207,12 +201,16 @@ class SheetQueryBuilder { * @param {UpdateFn} updateFn * @return {SheetQueryBuilder} */ - updateRows(updateFn) { + updateRows(updateFn, safe = false) { updateFn = (typeof updateFn == 'object') ? update_fn(updateFn) : updateFn; const rows = this.getTable(); - for (let i = 0; i < rows.length; i++) { - this.updateRow(rows[i], updateFn); - } + if (rows.length == 0) + throw new Error('filter function did not match anything'); + for (let i = 0; i < rows.length; i++) + if (safe) + this.updateRowSafe(rows[i], updateFn); + else + this.updateRow(rows[i], updateFn); this.clearCache(); return this; } @@ -241,12 +239,72 @@ class SheetQueryBuilder { updateRowRange.setValues([newValues]); return this; } + /** + * Updates specific cells in a row without implicitly overriding other cell values or formulas. + * @param {object} row The row object (from getRows()) containing __meta and column data. + * @param {object|function(object): object} updateFn An object with key-value pairs for updates, + * @return {SheetQueryBuilder} + */ + updateRowSafe(row, updateFn) { + updateFn = (typeof updateFn == 'object') ? update_fn(updateFn) : updateFn; + + const sheet = this.getSheet(); + const headings = this.getHeadings(); + const rowMeta = row.__meta; + const oldRow = {...row}; + updateFn(row); + delete row.__meta; + + // Iterate over the keys (column names) in the updatedRow object + for (const columnName in row) { + if (row[columnName] == oldRow[columnName]) + continue; + + const newValue = row[columnName]; + const columnIndex = headings.indexOf(columnName); + if (columnIndex === -1) + throw new Error(`${columnName} not found`) + const targetCell = sheet.getRange(rowMeta.row, columnIndex + 1); + const valueToSet = (newValue === undefined || newValue === null || newValue === false) ? '' : newValue; + targetCell.setValue(valueToSet); + } + return this; + } + /** + * Sets all values in a specified column by its name. + * + * @param {string} columnName The name of the column to update. + * @param {any} value The single value to set for all cells in the column. + * @return {SheetQueryBuilder} + */ + setColumnValues(columnName, value) { + const sheet = this.getSheet(); + if (!sheet) { + throw new Error('SheetQuery: No sheet selected or sheet not found.'); + } + + const headings = this.getHeadings(); + const columnIndex = headings.indexOf(columnName); + + if (columnIndex === -1) + throw new Error(`SheetQuery: Column '${columnName}' not found in sheet '${this.sheetName}'.`); + + const sheetColumnIndex = columnIndex + 1; + const lastRow = sheet.getLastRow(); + const headingRow = this.headingRow; + const targetRange = sheet.getRange(headingRow + 1, sheetColumnIndex, lastRow - headingRow, 1); + targetRange.setValue(value); + this.clearCache(); // Clear cache to reflect changes + + return this; + } /** * Clear cached values, headings, and flush all operations to sheet * * @return {SheetQueryBuilder} */ clearCache() { + this.whereFn = null; this._sheetValues = null; this._sheetHeadings = []; SpreadsheetApp.flush(); From 83f1680b05b19a4a4377c075ef35d4f988d88203 Mon Sep 17 00:00:00 2001 From: Bunnarin <161002845+Bunnarin@users.noreply.github.com> Date: Sun, 29 Jun 2025 20:07:34 +0700 Subject: [PATCH 4/7] fixed deleteRows and updateRows getting its rows with header --- sheetquery.gs | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/sheetquery.gs b/sheetquery.gs index 9827f0a..60eeacd 100644 --- a/sheetquery.gs +++ b/sheetquery.gs @@ -123,7 +123,7 @@ class SheetQueryBuilder { * @returns {any[]} */ getCells() { - const rows = this.getTable(); + const rows = this.getRows(); const returnValues = []; rows.forEach((row) => { returnValues.push(this._sheet.getRange(row.__meta.row, 1, 1, row.__meta.cols).getValue()); @@ -185,7 +185,7 @@ class SheetQueryBuilder { * @return {SheetQueryBuilder} */ deleteRows() { - const rows = this.getTable(); + const rows = this.getRows(); let i = 0; rows.forEach((row) => { const deleteRowRange = this._sheet.getRange(row.__meta.row - i, 1, 1, row.__meta.cols); @@ -203,7 +203,7 @@ class SheetQueryBuilder { */ updateRows(updateFn, safe = false) { updateFn = (typeof updateFn == 'object') ? update_fn(updateFn) : updateFn; - const rows = this.getTable(); + const rows = this.getRows(); if (rows.length == 0) throw new Error('filter function did not match anything'); for (let i = 0; i < rows.length; i++) From 2349555274042d5f1f9376ef2e3759b0bd237240 Mon Sep 17 00:00:00 2001 From: Bunnarin <161002845+Bunnarin@users.noreply.github.com> Date: Mon, 30 Jun 2025 11:08:36 +0700 Subject: [PATCH 5/7] fixed .getRows() excluding the last row --- sheetquery.gs | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sheetquery.gs b/sheetquery.gs index 60eeacd..52d3cfa 100644 --- a/sheetquery.gs +++ b/sheetquery.gs @@ -89,7 +89,7 @@ class SheetQueryBuilder { * @return {RowObject[]} */ getRows() { - const sheetValues = this.getValues().slice(1, -1); + const sheetValues = this.getValues().slice(1); return this.whereFn ? sheetValues.filter(this.whereFn) : sheetValues; } /** From a9b0b467d7bcd6edf2f3e5ffea828801b772daf5 Mon Sep 17 00:00:00 2001 From: Bunnarin <161002845+Bunnarin@users.noreply.github.com> Date: Thu, 3 Jul 2025 15:49:24 +0700 Subject: [PATCH 6/7] fixed updateRow edge case where we need the row.__meta, but it already deleted --- sheetquery.gs | 12 +++++++----- 1 file changed, 7 insertions(+), 5 deletions(-) diff --git a/sheetquery.gs b/sheetquery.gs index 52d3cfa..2723e84 100644 --- a/sheetquery.gs +++ b/sheetquery.gs @@ -219,15 +219,16 @@ class SheetQueryBuilder { */ updateRow(row, updateFn) { updateFn = (typeof updateFn == 'object') ? update_fn(updateFn) : updateFn; - const updatedRow = updateFn(row) || row; - const rowMeta = updatedRow.__meta; + updateFn(row) || row; + const rowMeta = row.__meta; const headings = this.getHeadings(); - delete updatedRow.__meta; + delete row.__meta; // Put new array data in order of headings in sheet const arrayValues = headings.map((heading) => { - const val = updatedRow[heading]; + const val = row[heading]; return val === undefined || val === null || val === false ? '' : val; }); + row.__meta = rowMeta; //reattach to avoid edge case where we update the same row again const maxCols = Math.max(rowMeta.cols, arrayValues.length); const updateRowRange = this.getSheet().getRange(rowMeta.row, 1, 1, maxCols); const rangeData = updateRowRange.getValues()[0] || []; @@ -255,7 +256,7 @@ class SheetQueryBuilder { updateFn(row); delete row.__meta; - // Iterate over the keys (column names) in the updatedRow object + // Iterate over the keys (column names) in the row object for (const columnName in row) { if (row[columnName] == oldRow[columnName]) continue; @@ -268,6 +269,7 @@ class SheetQueryBuilder { const valueToSet = (newValue === undefined || newValue === null || newValue === false) ? '' : newValue; targetCell.setValue(valueToSet); } + row.__meta = rowMeta; //reattach to avoid edge case where we update the same row again return this; } /** From c109ef54d0857ebb60c3bc719a33836858577541 Mon Sep 17 00:00:00 2001 From: Bunnarin <161002845+Bunnarin@users.noreply.github.com> Date: Fri, 11 Jul 2025 08:55:34 +0700 Subject: [PATCH 7/7] optimized insertRows() to be faster by using setValues instead --- sheetquery.gs | 19 +++++++++++++------ 1 file changed, 13 insertions(+), 6 deletions(-) diff --git a/sheetquery.gs b/sheetquery.gs index 2723e84..4980d16 100644 --- a/sheetquery.gs +++ b/sheetquery.gs @@ -164,19 +164,26 @@ class SheetQueryBuilder { insertRows(newRows) { const sheet = this.getSheet(); const headings = this.getHeadings(); + const allRowsToInsert = []; + newRows.forEach((row) => { - if (!row) { + if (!row) return; - } + const rowValues = headings.map((heading) => { const val = row[heading]; return val === undefined || val === null || val === false ? '' : val; }); - // appendRow() will throw if array is empty, so we check to prevent that - if (rowValues && rowValues.length !== 0) { - sheet.appendRow(rowValues); - } + allRowsToInsert.push(rowValues); }); + + const startRow = sheet.getLastRow() + 1; + const numRows = allRowsToInsert.length; + const numCols = headings.length; + const targetRange = sheet.getRange(startRow, 1, numRows, numCols); + targetRange.setValues(allRowsToInsert); + + this.clearCache(); // Clear cache to reflect changes in the sheet return this; } /**