Skip to content

Instantly share code, notes, and snippets.

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 HeatfanJohn/d37c5bcd288e41a0b6ed to your computer and use it in GitHub Desktop.
Save HeatfanJohn/d37c5bcd288e41a0b6ed to your computer and use it in GitHub Desktop.
google sheets text to columns
/* lifted from http://storage.pardot.com/10212/69581/text_to_columns_script.txt */
/**
* Retrieves all the rows in the active spreadsheet that contain data and logs the
* values for each row.
* For more information on using the Spreadsheet API, see
* https://developers.google.com/apps-script/service_spreadsheet
*/
function readRows() {
var sheet = SpreadsheetApp.getActiveSheet();
var rows = sheet.getDataRange();
var numRows = rows.getNumRows();
var values = rows.getValues();
for (var i = 0; i <= numRows - 1; i++) {
var row = values[i];
Logger.log(row);
}
};
/**
* Adds a custom menu to the active spreadsheet, containing a single menu item
* for invoking the readRows() function specified above.
* The onOpen() function, when defined, is automatically invoked whenever the
* spreadsheet is opened.
* For more information on using the Spreadsheet API, see
* https://developers.google.com/apps-script/service_spreadsheet
*/
function onOpen() {
var ss = SpreadsheetApp.getActiveSpreadsheet();
var menuEntries = [];
menuEntries.push({ name:"Text to columns", functionName:"textToColumns" });
menuEntries.push({ name:"Text to columns (custom separator)", functionName:"textToColumnsCustom" });
menuEntries.push(null);
menuEntries.push({ name:"Columns to Text", functionName:"columnsToText" });
menuEntries.push({ name:"Columns to Text (custom separator)", functionName:"columnsToTextCustom" });
ss.addMenu("Advanced", menuEntries);
}
function textToColumnsCustom() {
var separator = Browser.inputBox("Text to column","Enter the the separator",Browser.Buttons.OK);
textToColumns(separator);
}
// Expands a single cell of CSV formatted text to multiple columns
function textToColumns(separator) {
var sep = typeof(separator) !== 'undefined' ? separator : ',';
var ss = SpreadsheetApp.getActiveSheet();
var r = ss.getActiveRange();
// check that only one column was selected
var col = r.getColumn();
if(col !== r.getLastColumn()) {
Browser.msgBox("Error", "Invalid selection, too many columns.", Browser.Buttons.OK);
return;
}
var firstRow = r.getRow();
// short cut the one row selection
if(firstRow === r.getLastRow()) {
var values = r.getValues().toString().split(sep);
ss.getRange(firstRow,col+1,1,values.length).setValues(new Array(values));
return;
} else {
var rows = r.getValues();
var values = [];
var cols = 0;
for(var i = 0, len = rows.length; i < len; i++) {
var rowValues = rows[i].toString().split(sep);
var rowValuesLen = rowValues.length;
if(cols < rowValuesLen) { cols = rowValuesLen; }
values.push(rowValues);
}
// set all values at once (padding required because setValues doesn't accept jagged 2d arrays)
padRow(values, cols);
ss.getRange(firstRow,col+1,values.length,cols).setValues(values);
}
}
// Pads a row with empty values to the specified length
function padRow(array, length) {
for(var i = 0; i < array.length; i++) {
var arrLen = array[i].length;
if(arrLen < length) {
var padLen = length - arrLen;
var padding = new Array(padLen);
array[i].push.apply(array[i], padding);
for(var j = 0, len = array[i].length; j < len; j++) {
if(typeof(array[i][j]) === 'undefined') {
array[i][j] = "";
}
}
}
}
return array;
}
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment