Back in 2011 I showed how you can use Google Apps Script to write POST/GET data to a Google Sheet. Over the years a couple of things have changed in Apps Script so I thought it was worth a revisit. The main changes are:
- using LockService to prevent concurrent write access
- switching to the new PropertiesService to store script data
- using the ContentService to return JSON (this makes it easy to use ajax in data requests)
The core concept behind the script is the same. You have a Google Sheet with a set of header column names that matches the names of the data you are passing through. For example if I had a form with:
<input name="bar" type="text" value="" />
I’d need a sheet with the column name ‘bar’. For this post I’m going to assume we use a container bound Apps Script in a Google Sheet, but you could easily modify this for a standalone script. So to start you can either create or open an existing Sheet and click Tools > Script editor and enter the code below or copy this template.
Usage
There are a couple of ways you can use this script to collect data. You could use a very traditional HTML form using the web app url as the action parameter. This would send users to a very unattractive JSON response which you could alternatively beautify using the HTMLService. A nicer solution is to use AJAX to submit the data without refreshing or moving page. Here is a simple form based on this Stackoverflow jQuery Ajax POST example which sends responses to this Google Sheet:
The only real change to the stackoverflow example is to specify the destination web app url:
// fire off the request to /form.php request = $.ajax({ url: "https://script.google.com/macros/s/AKfycbzV--xTooSkBLufMs4AnrCTdwZxVNtycTE4JNtaCze2UijXAg8/exec", type: "post", data: serializedData });
The example is using POST but you can also use GET. There is more you can do when handling the data at the Apps Script end other than writing to a Google Sheet. For example, if you wanted to send an email on each submission you could use the MailApp service and add something like:
MailApp.sendEmail("youremailaddress", "a subject", JSON.stringify(e.parameters));
in the try
statement. If you do this there are a couple of things to remember. First Apps Script web apps using versioning. This means changes to your script are not ‘live’ until you push a new version. To do this you need to save your new script and then from the Script Editor select File > Manage versions… and ‘Save New Version’ before going into Publish > Deploy as web app and updating Project Version. Also when you add new services to your script the authentication scope changes and you need to approve additional services. For example, if you add the MailApp service to your code you need to give permission to send email. The easiest way to trigger this in this example is in the Script Editor Run > setup. I’m sure there are other trip ups but hopefully this gets you most of the way
Google Sheet/Apps Script Code
// 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. /* // If you are passing JSON in the body of the request uncomment this block var jsonString = e.postData.getDataAsString(); e.parameter = JSON.parse(jsonString); */ 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()); }
Google Sheets as a Database - INSERT with Apps ...
[…] Back in 2011 I showed how you can use Google Apps Script to write POST/GET data to a Google Sheet. Over the years a couple of things have changed in Apps Script so I thought it was worth a revisit. This version uses features like LockService, PropertiesService and ContentService to make it more robust and make it possible to do ajax powered form submissions. The post includes a couple of tips that appear to be catching people out including versioning and permissions scope. […]