Skip to content

Instantly share code, notes, and snippets.

@embarq
Created October 7, 2016 08:45
Show Gist options
  • Save embarq/23186ab237fae5413e867be35f6b8747 to your computer and use it in GitHub Desktop.
Save embarq/23186ab237fae5413e867be35f6b8747 to your computer and use it in GitHub Desktop.
Google AppsScript macro for Google Forms and Google Sheets. Script should be installed by running "Initialize" function. Sorts form's response data by user gender. Append data after last row that contains any data(Prevent unnecessary whitespace between rows)
function isSheetExist(sheetName) {
return SpreadsheetApp.getActiveSpreadsheet().getSheetByName(sheetName) != null;
}
function formResponseFilter(e) {
if (!e) throw new Error("Please go the Run menu and choose Initialize");
try {
var ss = SpreadsheetApp.getActiveSpreadsheet();
var base = ss.getSheets()[0];
var sheet = null;
var sheetName = e.namedValues["Gender"].toString();
if (isSheetExist(sheetName)) {
sheet = ss.setActiveSheet(ss.getSheetByName(sheetName));
} else {
sheet = ss.setActiveSheet(ss.insertSheet(sheetName));
base.getRange(1, 1, 1, base.getLastColumn()).copyTo(sheet.getRange(1, 1, 1, 1));
sheet.setFrozenRows(1);
}
sheet.appendRow(e.values);
}
catch (error) {
Logger.log(error.toString());
}
ss.setActiveSheet(ss.getSheets()[0]);
}
function fillEmptyRows() {
var start = new Date().getTime();
var sheet = SpreadsheetApp.getActiveSheet();
var rows = sheet.getLastRow(), cols = sheet.getLastColumn();
Logger.log(rows); if (rows == 1 || rows == 2) return;
var range = sheet.getRange(2, 1, rows, cols).getValues();
range = range.filter(
function(sub_arr) {
return sub_arr.some(
function(elem) {
return elem != ""
});
});
sheet.getRange(2, 1, rows, cols).clearContent();
sheet.getRange(2, 1, range.length, cols).setValues(range);
var end = new Date().getTime();
Logger.log('"fillEmptyRows" function execution time = %s', (end - start).toString());
}
function Initialize() {
try {
var triggers = ScriptApp.getProjectTriggers();
for (var i in triggers)
ScriptApp.deleteTrigger(triggers[i]);
ScriptApp.newTrigger("formResponseFilter")
.forSpreadsheet(SpreadsheetApp.getActiveSpreadsheet())
.onFormSubmit().create();
ScriptApp.newTrigger("fillEmptyRows")
.forSpreadsheet(SpreadsheetApp.getActiveSpreadsheet())
.onEdit().create();
} catch (error) {
throw new Error("Please add this code in the Google Spreadsheet");
}
}
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment