Skip to content

Instantly share code, notes, and snippets.

@Lukas238
Created November 28, 2017 18:41
Show Gist options
  • Save Lukas238/9ac118634c99baa0d3bd026ca06f19e8 to your computer and use it in GitHub Desktop.
Save Lukas238/9ac118634c99baa0d3bd026ca06f19e8 to your computer and use it in GitHub Desktop.
Google Spreadsheet Script to handle and save POST data

Google Spreadsheet Script to handle and save POST data

//  1. Enter sheet name where data is to be written below
var SHEET_NAME = "Data";
         
//  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 = []; 
    
    
    //Parse the submited values as an array
    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
//        if(e.parameter[headers[i]] !== undefined){
          row.push(e.parameter[headers[i]]);
//        }
      }
    }
    
    if(row.length ){
      Logger.log("Row: " + row);
      var match_row = findRowByValue(sheet, "A", row[0] );
      if( match_row ){ 
        // Update an existing row with the array
        sheet.getRange(match_row, 1, 1, row.length).setValues([row]);
      }else{
        // Save the array in a new row
        sheet.getRange(nextRow, 1, 1, row.length).setValues([row]);
      }
    }
    // Save the array in a new row
//    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 findRowByValue(sheet, column, value) {
  var column = sheet.getRange(column + ":" + column);  // like A2:A, this will exclude the header row #1
  var values = column.getValues();

  for (var i = 0; i < values.length; i++) {
    for (var j = 0; j < values[i].length; j++) {     
      if (values[i][j] == value) {
        Logger.log(i);
        return i+1;
      }
    }    
   }
  return false;
}

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