Skip to content

Instantly share code, notes, and snippets.

@simonepri
Forked from pamelafox/exportjson.js
Last active June 20, 2021 10:57
Show Gist options
  • Save simonepri/c3e62eb0291d3230d0d0481cf18c3480 to your computer and use it in GitHub Desktop.
Save simonepri/c3e62eb0291d3230d0d0481cf18c3480 to your computer and use it in GitHub Desktop.
// Includes functions for exporting active sheet or all sheets as JSON object (also Python object syntax compatible).
// Tweak the makePrettyJSON_ function to customize what kind of JSON to export.
var FORMAT_ONELINE = 'One-line';
var FORMAT_MULTILINE = 'Multi-line';
var FORMAT_PRETTY = 'Pretty';
var LANGUAGE_JS = 'JavaScript';
var LANGUAGE_PYTHON = 'Python';
var STRUCTURE_LIST = 'List';
var STRUCTURE_HASH = 'Hash (keyed by "id" column)';
/* Defaults for this particular spreadsheet, change as desired */
var DEFAULT_FORMAT = FORMAT_PRETTY;
var DEFAULT_LANGUAGE = LANGUAGE_JS;
var DEFAULT_STRUCTURE = STRUCTURE_LIST;
var DEFUALT_NORMALIZE = 'true';
var DEFUALT_DETECT_OBJ = 'true';
function onOpen() {
var ss = SpreadsheetApp.getActiveSpreadsheet();
var menuEntries = [
{name: "Export JSON for this sheet", functionName: "exportSheet"},
{name: "Export JSON for all sheets", functionName: "exportAllSheets"},
{name: "Configure export", functionName: "exportOptions"},
];
ss.addMenu("Export JSON", menuEntries);
}
function exportOptions() {
var doc = SpreadsheetApp.getActiveSpreadsheet();
var app = UiApp.createApplication().setTitle('Export JSON');
var grid = app.createGrid(6, 2);
grid.setWidget(0, 0, makeLabel(app, 'Language:'));
grid.setWidget(0, 1, makeListBox(app, 'language', [LANGUAGE_JS, LANGUAGE_PYTHON]));
grid.setWidget(1, 0, makeLabel(app, 'Format:'));
grid.setWidget(1, 1, makeListBox(app, 'format', [FORMAT_PRETTY, FORMAT_MULTILINE, FORMAT_ONELINE]));
grid.setWidget(2, 0, makeLabel(app, 'Structure:'));
grid.setWidget(2, 1, makeListBox(app, 'structure', [STRUCTURE_LIST, STRUCTURE_HASH]));
grid.setWidget(3, 0, makeLabel(app, 'Normalize Headers:'));
grid.setWidget(3, 1, makeCheckBox(app, 'normalize'));
grid.setWidget(4, 0, makeLabel(app, 'Detect Objects and Arrays:'));
grid.setWidget(4, 1, makeCheckBox(app, 'detectObj'));
grid.setWidget(5, 0, makeButton(app, grid, 'Export Active Sheet', 'exportSheet'));
grid.setWidget(5, 1, makeButton(app, grid, 'Export All Sheets', 'exportAllSheets'));
app.add(grid);
doc.show(app);
}
function makeLabel(app, text, id) {
var lb = app.createLabel(text);
if (id) lb.setId(id);
return lb;
}
function makeListBox(app, name, items) {
var listBox = app.createListBox().setId(name).setName(name);
listBox.setVisibleItemCount(1);
var cache = CacheService.getPublicCache();
var selectedValue = cache.get(name);
Logger.log(selectedValue);
for (var i = 0; i < items.length; i++) {
listBox.addItem(items[i]);
if (items[1] == selectedValue) {
listBox.setSelectedIndex(i);
}
}
return listBox;
}
function makeButton(app, parent, name, callback) {
var button = app.createButton(name);
app.add(button);
var handler = app.createServerClickHandler(callback).addCallbackElement(parent);;
button.addClickHandler(handler);
return button;
}
function makeTextBox(app, name) {
var textArea = app.createTextArea().setWidth('100%').setHeight('200px').setId(name).setName(name);
return textArea;
}
function makeCheckBox(app, name) {
var checkBox = app.createCheckBox().setId(name).setName(name);
var cache = CacheService.getPublicCache();
var selectedValue = cache.get(name) == 'true';
Logger.log(selectedValue);
checkBox.setValue(selectedValue);
return checkBox;
}
function exportAllSheets(e) {
var ss = SpreadsheetApp.getActiveSpreadsheet();
var sheets = ss.getSheets();
var sheetsData = {};
for (var i = 0; i < sheets.length; i++) {
var sheet = sheets[i];
var rowsData = getRowsData_(sheet, getExportOptions(e));
var sheetName = sheet.getName();
sheetsData[sheetName] = rowsData;
}
var json = makeJSON_(sheetsData, getExportOptions(e));
return displayText_(json);
}
function exportSheet(e) {
var ss = SpreadsheetApp.getActiveSpreadsheet();
var sheet = ss.getActiveSheet();
var rowsData = getRowsData_(sheet, getExportOptions(e));
var json = makeJSON_(rowsData, getExportOptions(e));
return displayText_(json);
}
function getExportOptions(e) {
var options = {};
options.language = e && e.parameter.language || DEFAULT_LANGUAGE;
options.format = e && e.parameter.format || DEFAULT_FORMAT;
options.structure = e && e.parameter.structure || DEFAULT_STRUCTURE;
options.normalize = e && e.parameter.normalize || DEFUALT_NORMALIZE;
options.detectObj = e && e.parameter.detectObj || DEFUALT_DETECT_OBJ;
var cache = CacheService.getPublicCache();
cache.put('language', options.language);
cache.put('format', options.format);
cache.put('structure', options.structure);
cache.put('normalize', options.normalize);
cache.put('detectObj', options.detectObj);
Logger.log(options);
return options;
}
function makeJSON_(object, options) {
Logger.log(options);
if (options.detectObj == 'true') {
var obj, o;
for (var i = 0; i < object.length; i++) {
obj = object[i];
if (!obj) continue;
for (prop in obj) {
o = obj[prop].toString();
if(!o) continue;
if(o[0] === '{' && o[o.length-1] == '}' || o[0] === '[' && o[o.length-1] == ']') {
object[i][prop] = JSON.parse(o);
}
}
}
}
if (options.format == FORMAT_PRETTY) {
var jsonString = JSON.stringify(object, null, 4);
} else if (options.format == FORMAT_MULTILINE) {
var jsonString = Utilities.jsonStringify(object);
jsonString = jsonString.replace(/},/gi, '},\n');
jsonString = prettyJSON.replace(/":\[{"/gi, '":\n[{"');
jsonString = prettyJSON.replace(/}\],/gi, '}],\n');
} else {
var jsonString = Utilities.jsonStringify(object);
}
if (options.language == LANGUAGE_PYTHON) {
// add unicode markers
jsonString = jsonString.replace(/"([a-zA-Z]*)":\s+"/gi, '"$1": u"');
}
return jsonString;
}
function displayText_(text) {
var app = UiApp.createApplication().setTitle('Exported JSON');
app.add(makeTextBox(app, 'json'));
app.getElementById('json').setText(text);
var ss = SpreadsheetApp.getActiveSpreadsheet();
ss.show(app);
return app;
}
// getRowsData iterates row by row in the input range and returns an array of objects.
// Each object contains all the data for a given row, indexed by its normalized column name.
// Arguments:
// - sheet: the sheet object that contains the data to be processed
// - range: the exact range of cells where the data is stored
// - columnHeadersRowIndex: specifies the row number where the column names are stored.
// This argument is optional and it defaults to the row immediately above range;
// Returns an Array of objects.
function getRowsData_(sheet, options) {
var headersRange = sheet.getRange(1, 1, sheet.getFrozenRows(), sheet.getMaxColumns());
var headers = headersRange.getValues()[0];
var dataRange = sheet.getRange(sheet.getFrozenRows()+1, 1, sheet.getMaxRows(), sheet.getMaxColumns());
var objects;
if (options.normalize == 'true') {
objects = getObjects_(dataRange.getValues(), normalizeHeaders_(headers));
} else {
objects = getObjects_(dataRange.getValues(), headers);
}
if (options.structure == STRUCTURE_HASH) {
var objectsById = {};
objects.forEach(function(object) {
objectsById[object.id] = object;
});
return objectsById;
} else {
return objects;
}
}
// getColumnsData iterates column by column in the input range and returns an array of objects.
// Each object contains all the data for a given column, indexed by its normalized row name.
// Arguments:
// - sheet: the sheet object that contains the data to be processed
// - range: the exact range of cells where the data is stored
// - rowHeadersColumnIndex: specifies the column number where the row names are stored.
// This argument is optional and it defaults to the column immediately left of the range;
// Returns an Array of objects.
function getColumnsData_(sheet, range, rowHeadersColumnIndex, options) {
rowHeadersColumnIndex = rowHeadersColumnIndex || range.getColumnIndex() - 1;
var headersTmp = sheet.getRange(range.getRow(), rowHeadersColumnIndex, range.getNumRows(), 1).getValues();
var headers;
if (options.normalize == 'true') {
headers = normalizeHeaders_(arrayTranspose_(headersTmp)[0]);
} else {
headers = arrayTranspose_(headersTmp)[0];
}
return getObjects(arrayTranspose_(range.getValues()), headers);
}
// For every row of data in data, generates an object that contains the data. Names of
// object fields are defined in keys.
// Arguments:
// - data: JavaScript 2d array
// - keys: Array of Strings that define the property names for the objects to create
function getObjects_(data, keys) {
var objects = [];
for (var i = 0; i < data.length; ++i) {
var object = {};
var hasData = false;
for (var j = 0; j < data[i].length; ++j) {
var cellData = data[i][j];
if (isCellEmpty_(cellData)) {
continue;
}
if (typeof cellData === 'string' && cellData.trim().toLowerCase() == "null" ) {
cellData = null;
}
object[keys[j]] = cellData;
hasData = true;
}
if (hasData) {
objects.push(object);
}
}
return objects;
}
// Returns an Array of normalized Strings.
// Arguments:
// - headers: Array of Strings to normalize
function normalizeHeaders_(headers) {
var keys = [];
for (var i = 0; i < headers.length; ++i) {
var key = normalizeHeader_(headers[i]);
if (key.length > 0) {
keys.push(key);
}
}
return keys;
}
// Normalizes a string, by removing all alphanumeric characters and using mixed case
// to separate words. The output will always start with a lower case letter.
// This function is designed to produce JavaScript object property names.
// Arguments:
// - header: string to normalize
// Examples:
// "First Name" -> "firstName"
// "Market Cap (millions) -> "marketCapMillions
// "1 number at the beginning is ignored" -> "numberAtTheBeginningIsIgnored"
function normalizeHeader_(header) {
var key = "";
var upperCase = false;
for (var i = 0; i < header.length; ++i) {
var letter = header[i];
if (letter == " " && key.length > 0) {
upperCase = true;
continue;
}
if (!isAlnum_(letter)) {
continue;
}
if (key.length == 0 && isDigit_(letter)) {
continue; // first character must be a letter
}
if (upperCase) {
upperCase = false;
key += letter.toUpperCase();
} else {
key += letter.toLowerCase();
}
}
return key;
}
// Returns true if the cell where cellData was read from is empty.
// Arguments:
// - cellData: string
function isCellEmpty_(cellData) {
return typeof(cellData) == "string" && cellData == "";
}
// Returns true if the character char is alphabetical, false otherwise.
function isAlnum_(char) {
return char >= 'A' && char <= 'Z' ||
char >= 'a' && char <= 'z' ||
isDigit_(char);
}
// Returns true if the character char is a digit, false otherwise.
function isDigit_(char) {
return char >= '0' && char <= '9';
}
// Given a JavaScript 2d Array, this function returns the transposed table.
// Arguments:
// - data: JavaScript 2d Array
// Returns a JavaScript 2d Array
// Example: arrayTranspose([[1,2,3],[4,5,6]]) returns [[1,4],[2,5],[3,6]].
function arrayTranspose_(data) {
if (data.length == 0 || data[0].length == 0) {
return null;
}
var ret = [];
for (var i = 0; i < data[0].length; ++i) {
ret.push([]);
}
for (var i = 0; i < data.length; ++i) {
for (var j = 0; j < data[i].length; ++j) {
ret[j][i] = data[i][j];
}
}
return ret;
}
@iamihgam
Copy link

Hello, is it possible to export selected rows in the active sheets as json objects. Thank you

@sudoalx
Copy link

sudoalx commented Apr 15, 2020

Hello, is it possible to export selected rows in the active sheets as json objects. Thank you

I am trying to approach this. Have you find a way to do it?

@vikivyas
Copy link

Exception: UiApp has been deprecated. Please use HtmlService instead.Details

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment