Created
August 18, 2014 14:20
-
-
Save bmcbride/7069aebd643944c9ee8b to your computer and use it in GitHub Desktop.
Google Apps Script for POSTING JSON data to a Google Sheet. via http://mashe.hawksey.info/2014/07/google-sheets-as-a-database-insert-with-apps-script-using-postget-methods-with-ajax-example/
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
// Create or open an existing Sheet and click Tools > Script editor and enter the code below | |
// 1. Enter sheet name where data is to be written below | |
var SHEET_NAME = "Sheet1"; | |
// 2. Run > setup | |
// 3. 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) | |
// 4. Copy the 'Current web app URL' and post this in your form/script action | |
// 5. Insert column names on your destination sheet matching the parameter names of the data you are passing in (exactly matching case) | |
var SCRIPT_PROP = PropertiesService.getScriptProperties(); // new property service | |
// If you don't want to expose either GET or POST methods you can comment out the appropriate function | |
function doGet(e){ | |
return handleResponse(e); | |
} | |
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. | |
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(SHEET_NAME); | |
// we'll assume header is in row 1 but you can override with header_row in GET/POST data | |
var headRow = e.parameter.header_row || 1; | |
var headers = sheet.getRange(1, 1, 1, sheet.getLastColumn()).getValues()[0]; | |
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(new Date()); | |
} else { // else use header name to get data | |
row.push(e.parameter[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", "row": nextRow})) | |
.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
Hi, I'm using the modified version of the above code.gs from here.
`// 2017 by Daniel Eichhorn, https://blog.squix.org
// Inspired by https://gist.github.com/bmcbride/7069aebd643944c9ee8b
// Create or open an existing Sheet and click Tools > Script editor and enter the code below
// 1. Enter sheet name where data is to be written below
var SHEET_NAME = "Sheet1";
// 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
var SCRIPT_PROP = PropertiesService.getScriptProperties(); // new property service
// If you don't want to expose either GET or POST methods you can comment out the appropriate function
function doGet(e){
return handleResponse(e);
}
function doPost(e){
return handleResponse(e);
}
function handleResponse(e) {
Logger.log("arrived in handleResponse");
if(typeof e !== 'undefined')
var jsonData = JSON.parse(e.postData.contents);
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(SHEET_NAME);
} catch(e) {
// if error return this
return ContentService
.createTextOutput(JSON.stringify({"result":"error", "error": e}))
.setMimeType(ContentService.MimeType.JSON);
}
}`
I get "TypeError: Cannot read property "contents" from undefined. (line 25, file "Code")" when put the URL of the deployed web app. It suggests that the jsonData maybe empty.
Actually, I'm doing a LoRa communication project where I get the GPS data from the Loriot server and post to the Google sheet which is same as the link that I get the modified Code.gs from.
In my application log in the Loriot server shows:
Error POSTing message | "err":"POSTing message to "https://script.google.com/macros/s/AKfycbyUaIl4t8PZxoXswCW2kc0I-ZfUl5DVucsD0CwtW3Rn4YAP2qpo/exec\" failed with 302 status code","appid":3195667320,"url":"https://script.google.com/macros/s/AKfycbyUaIl4t8PZxoXswCW2kc0I-ZfUl5DVucsD0CwtW3Rn4YAP2qpo/exec","seqno":641,"deveui":"47A9B2690026003A","data":{"statusCode":302},"message":"POSTing message to "https://script.google.com/macros/s/AKfycbyUaIl4t8PZxoXswCW2kc0I-ZfUl5DVucsD0CwtW3Rn4YAP2qpo/exec\" failed with 302 status code","targetUrl":"https://script.google.com/macros/s/AKfycbyUaIl4t8PZxoXswCW2kc0I-ZfUl5DVucsD0CwtW3Rn4YAP2qpo/exec","statusCode":302,"reqBody":null,"errName":"Error","instance":"nwk-1"
I hope to get some comment from Sir, as I stuck for many months on the issue of failed with 302 status and TypeError: Cannot read property "contents" from undefined. (line 25, file "Code"). Thanks a lot