Skip to content

Instantly share code, notes, and snippets.

@aindong
Created July 31, 2018 05:37
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save aindong/a89996f89d832e71ad9bc2e9222c96e9 to your computer and use it in GitHub Desktop.
Save aindong/a89996f89d832e71ad9bc2e9222c96e9 to your computer and use it in GitHub Desktop.
Save data to spreadsheet
// https://script.google.com/macros/s/AKfycbxqaARMsIrSYKysoN5RByYe0PlWAgW9VrRi16p8IojhFKpgYpc/exec
function doGet(e){
//return handleResponse(e);
}
function doPost(e){
return handleResponse(e);
}
// Sheet name where data is to be written
var SHEET_NAME = "database";
var SHEET_KEY = "1HpzxBP34lAczWUFw8o7D5UINFDu3-jeTccs_3F6IgS4";
var SCRIPT_PROP = PropertiesService.getScriptProperties(); // new property service
function handleResponse(e) {
// [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(SHEET_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] == "email") {
var email = e.parameter[headers[i]];
var duplicate = checkDuplicateEmail(email);
console.log(duplicate)
if (duplicate) {
console.log("Duplicate for ", email);
return ContentService
.createTextOutput(JSON.stringify({"result":"error", "error": "duplicate_email"}))
.setMimeType(ContentService.MimeType.JSON);
}
}
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 testCheckDuplicateEmail() {
var duplicate = checkDuplicateEmail("test@email.com");
Logger.log(duplicate);
}
function checkDuplicateEmail(email) {
var s = SpreadsheetApp.openById(SHEET_KEY);
var emails = s.getRange("B2:B").getValues();
Logger.log("Testing " + email);
for (var i=0;i<emails.length;i++) {
if (emails[i][0] === email){
return true
}
}
//Do something when email not in the list
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