Skip to content

Instantly share code, notes, and snippets.

@jaiselrahman
Created September 18, 2021 11:40
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 jaiselrahman/4f97812cfbf45837d00edfcb22350578 to your computer and use it in GitHub Desktop.
Save jaiselrahman/4f97812cfbf45837d00edfcb22350578 to your computer and use it in GitHub Desktop.
Google Sheets Registration
// original from: http://mashe.hawksey.info/2014/07/google-sheets-as-a-database-insert-with-apps-script-using-postget-methods-with-ajax-example/
// original gist: https://gist.github.com/willpatera/ee41ae374d3c9839c2d6
function doPost(e){
return handleResponse(e);
}
function doGet(e){
return handleResponse(e);
}
// Enter sheet name where data is to be written below
var SHEET_NAME = "Sheet1";
var SCRIPT_PROP = PropertiesService.getScriptProperties(); // new property service
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(3000); // wait 3 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);
// Check if email is unique
var emailExists = sheet.getRange('D1:D')
.getValues()
.map(function(row) { return row[0]; })
.indexOf(e.parameter.Email) > -1;
if (emailExists) {
return ContentService
.createTextOutput(JSON.stringify({"result":"error", "error": "email_already_exists"}))
.setMimeType(ContentService.MimeType.JSON);
}
// Check if phone is unique
var phoneExists = sheet.getRange('E1:E')
.getValues()
.map(function(row) { return row[0].toString(); /* Make sure it is String */ })
.indexOf(e.parameter.Phone) > -1;
if (phoneExists) {
return ContentService
.createTextOutput(JSON.stringify({"result":"error", "error": "phone_already_exists"}))
.setMimeType(ContentService.MimeType.JSON);
}
// 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] == "Time"){ // special case if you include a 'time' 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]);
MailApp.sendEmail("flaminius2k19@gmail.com", "New Registration", registrationInformBody(e.parameters));
var aliases = GmailApp.getAliases();
GmailApp.sendEmail(e.parameter.Email, 'Thanks for registering', registrationReplyBody(e.parameters), {from: aliases[0], name:'Flaminius 2k19'});
// 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 registrationReplyBody(data) {
return "Hi " + data.Name +",\n\
\n\
Thanks for registering Flaminius 2k19 symposium. Hope you enjoy our symposium and we are looking forward to welcome you.\n\
\n\
Registration fee of amount Rs 250/- should be paid on symposium day.\n\
Please bring your College ID card.\n\
For more information visit: https://flaminius2k19.web.app\n\
or download our app: https://play.google.com/store/apps/details?id=app.flaminius.flaminius2k19\n\
\n\
For any queries reply to this email";
}
function registrationInformBody(data) {
return "\nName: " + data.Name +"\n\
Email: " + data.Email +"\n\
Phone: " + data.Phone +"\n\
College: " + data.College +"\n\
Department: " + data.Department +"\n\
Food Preference: " + data["Food Preference"] +"\n\
Time: " + new Date();
}
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