Last active
December 14, 2020 08:24
-
-
Save donysukardi/1991541a70c90ed8d1a120cb590f96f7 to your computer and use it in GitHub Desktop.
Google Sheets Apps Script
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
// 1. Run > setup | |
// - to set the document id | |
// | |
// 2. Publish > Deploy as web app | |
// - enter Project Version name and click 'Save New Version' | |
// - set security level and enable service (most likely execute as 'me' and access 'anyone, even anonymously) | |
// | |
// 3. Copy the 'Current web app URL' and post this in your form/script action | |
// | |
// 4. Insert column names on your destination sheet matching the parameter names of the data you are passing in (exactly matching case) | |
// | |
// Post data is sent to the web app URL (with support for `?sheetName=CustomSheetName`) with the following JSON schema | |
// { | |
// "header_row": "Optional, to indicate which row no is the header row", | |
// "columnHeader1": "Value 1", | |
// "columnHeader2": "Value 2", | |
// } | |
var SCRIPT_PROP = PropertiesService.getScriptProperties(); // new property service | |
function doPost(e){ | |
return handleResponse(e); | |
} | |
function handleResponse(e) { | |
// shortly after my original solution Google announced the LockService[1] | |
// this prevents concurrent access overwritting data | |
// [1] http://googleappsdeveloper.blogspot.co.uk/2011/10/concurrency-and-google-apps-script.html | |
// we want a public lock, one that locks for all invocations | |
var lock = LockService.getPublicLock(); | |
lock.waitLock(30000); // wait 30 seconds before conceding defeat. | |
var jsonString = e.postData.getDataAsString(); | |
var jsonData = JSON.parse(jsonString); | |
var data = [].concat(jsonData); | |
var sheetName = e.parameter.sheetName || 'Sheet1'; | |
try { | |
// next set where we write the data - you could write to multiple/alternate destinations | |
var doc = SpreadsheetApp.openById(SCRIPT_PROP.getProperty("key")); | |
var sheet = doc.getSheetByName(sheetName); | |
// we'll assume header is in row 1 | |
var headRow = 1; | |
var headers = sheet.getRange(1, 1, 1, sheet.getLastColumn()).getValues()[0]; | |
var timestamp = new Date(); | |
data.forEach(function(rowData) { | |
var nextRow = sheet.getLastRow()+1; // get next row | |
var row = []; | |
// loop through the header columns | |
for (i in headers){ | |
if (headers[i] == "Timestamp"){ // special case if you include a 'Timestamp' column | |
row.push(timestamp); | |
} else { // else use header name to get data | |
row.push(rowData[headers[i]]); | |
} | |
} | |
// more efficient to set values as [][] array than individually | |
sheet.getRange(nextRow, 1, 1, row.length).setValues([row]); | |
}); | |
// return json success results | |
return ContentService | |
.createTextOutput(JSON.stringify({"result":"success" })) | |
.setMimeType(ContentService.MimeType.JSON); | |
} catch(e){ | |
// if error return this | |
return ContentService | |
.createTextOutput(JSON.stringify({"result":"error", "error": e })) | |
.setMimeType(ContentService.MimeType.JSON); | |
} finally { //release lock | |
lock.releaseLock(); | |
} | |
} | |
function setup() { | |
var doc = SpreadsheetApp.getActiveSpreadsheet(); | |
SCRIPT_PROP.setProperty("key", doc.getId()); | |
} |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment