├── CONTRIBUTORS.md ├── .gitignore ├── LICENSE ├── selector.gs ├── README.md ├── item.gs └── table.gs /CONTRIBUTORS.md: -------------------------------------------------------------------------------- 1 | # Contributors 2 | 3 | - Philippe Oger 4 | - Guillem Orpinell 5 | - Alejandro Do Nascimento 6 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | # OSX 2 | .DS_Store 3 | .AppleDouble 4 | .LSOverride 5 | 6 | # SublimeText 7 | *.tmlanguage.cache 8 | *.tmPreferences.cache 9 | *.stTheme.cache 10 | *.sublime-workspace 11 | *.sublime-project 12 | 13 | # Logs 14 | *.log 15 | 16 | # Pycharm 17 | .idea 18 | 19 | # Vim 20 | *~ 21 | *.swp 22 | *.swo 23 | tags 24 | .ackrc 25 | 26 | # asdf 27 | .tool-versions 28 | 29 | # Ag Rg 30 | .ignore 31 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2018 Social Point 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /selector.gs: -------------------------------------------------------------------------------- 1 | /** 2 | * Constructor which creates a Selector object to query Items in a Table. 3 | * @param {Table} table: The Table object where to evaluate the criteria. 4 | * @param {Array} criteria: an array used as filter as an AND of ORs (see CNF). Examples: 5 | * >>> [{date: today}, [{tag: 1},{tag: 2}]] // (date === today && (tags === 1 || tags === 2)) 6 | * >>> [[{assigneeId: 'GO'}, {assigneeId: 'AM'}]] // (assigneeId === 'GO' || assigneeId === 'AM') 7 | * >>> [{name: 'Guillem'}, {surname: 'Orpinell'}] // (name === 'Guillem' && surname === 'Orpinell') 8 | * >>> {name: 'Guillem', surname: 'Orpinell'} // (name === 'Guillem' && surname === 'Orpinell') 9 | * @constructor 10 | */ 11 | function Selector(table, criteria) { 12 | this.table = table; 13 | this.criteria = criteria; 14 | this.queryItems = new GridArray(); 15 | } 16 | 17 | 18 | /** 19 | * Method to get the query items in a Selector object. 20 | */ 21 | Selector.prototype.getQueryItems = function() { 22 | return this.queryItems; 23 | } 24 | 25 | 26 | /** 27 | * Method to evaluate a criteria within a Table object. 28 | */ 29 | Selector.prototype.evaluate = function() { 30 | if (Array.isArray(this.criteria)) { 31 | var andsArray = this.criteria; 32 | } 33 | else if (isObject(this.criteria)) { 34 | var andsArray = [this.criteria]; 35 | } else { 36 | throw 'Oops! Criteria should be an Array or an Object. Fix it and try again.' 37 | } 38 | 39 | for (var i = 0; i < this.table.items.length; i++) { 40 | var item = this.table.items[i]; 41 | if (isMatching(item, andsArray)) { 42 | this.queryItems.push(item); 43 | } 44 | } 45 | return this 46 | } 47 | 48 | 49 | /** 50 | * Function to evaluate a criteria within an Item object. 51 | * @param {Item} item: The Item object where to evaluate the criteria. 52 | * @param {Array} criteria: an array used as filter as an AND of ORs (see CNF). 53 | @return {Boolean} 54 | */ 55 | function isMatching(item, andsArray) { 56 | for (var i=0; i < andsArray.length; i++) { 57 | var clause = andsArray[i]; 58 | if (isObject(clause) && someUnmatch(item, clause)) { //AND logic 59 | return false; 60 | } 61 | else if (Array.isArray(clause) && noneMatches(item, clause)) { //OR logic 62 | return false; 63 | } 64 | } 65 | return true; 66 | } 67 | 68 | /** 69 | * Function 70 | */ 71 | function someUnmatch(item, object) { 72 | for (var field in object) { 73 | if (!valuesMatch(object[field], item.getFieldValue(field))) { 74 | return true; 75 | } 76 | } 77 | return false; 78 | } 79 | 80 | /** 81 | * Function 82 | */ 83 | function noneMatches(item, orsArray) { 84 | for (var i=0; i < orsArray.length; i++) { 85 | var object = orsArray[i]; 86 | if (!isObject(object)) { 87 | throw 'Oops! The ORs array must be an array of Objects. Fix it and try again.' 88 | } 89 | for (var field in object) { 90 | if (valuesMatch(object[field], item.getFieldValue(field))) { 91 | return false; 92 | } 93 | } 94 | } 95 | return true; 96 | } 97 | 98 | /** 99 | * Function to check a matching between two values, considering also value as a Date. 100 | */ 101 | function valuesMatch(value1, value2) { 102 | return ((value1 instanceof Date && value1.getTime() === value2.getTime()) || value1 === value2) 103 | } 104 | 105 | /** 106 | * Returns if a value is an object 107 | */ 108 | function isObject (value) { 109 | return value && typeof value === 'object' && value.constructor.name === 'Object'; 110 | } -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | ### Sheetfu Table Class 2 | 3 | 4 | 5 | A Table object gives us the capability to treat a spreadsheet in a more ORM-like syntax in the Google Apps script environment. 6 | Let's see an example in an app script context, using a "people" sheet as below: 7 | 8 | | first_name | last_name | age | 9 | | ---------- | --------- | --- | 10 | | Philippe | Oger | 36 | 11 | | Guillem | Orpinell | 25 | 12 | | John | Doe | 32 | 13 | | Jane | Doe | 32 | 14 | 15 | 16 | ```javascript 17 | 18 | function tableClassQuickstart() { 19 | // Let's create a table and search for Philippe. 20 | var sheetName = 'people'; 21 | var headerRow = 1; 22 | var table = Sheetfu.getTable(sheetName, headerRow); 23 | var item = table.select({"first_name": "Philippe"}).first(); 24 | 25 | // get values, notes, etc.. 26 | var age = item.getFieldValue("age"); // 36 27 | var ageNote = item.getFieldNote("age"); 28 | var ageBackground = item.getFieldBackground("age"); 29 | 30 | // More importantly, we can set values, colors, notes. 31 | item.setFieldNote("age", "His birthday is coming soon") 32 | .setFieldValue("age", 37) 33 | .setFieldBackground("age", "red") 34 | .commit() 35 | } 36 | 37 | ``` 38 | 39 | We can also add new entries: 40 | 41 | ```javascript 42 | function addNewPerson() { 43 | var table = Sheetfu.getTable('people', 1); 44 | 45 | var newEmployee = { 46 | "first_name": "Albert", 47 | "last_name": "Einstein", 48 | "age": 138 49 | }; 50 | table.add(newEmployee); 51 | table.commit() 52 | } 53 | 54 | ``` 55 | 56 | More importantly, you can loop through every rows/items in the table the following way and add the execution worflow that you need. 57 | 58 | ```javascript 59 | function loopThroughItems() { 60 | var table = Sheetfu.getTable('people', 1); 61 | for (var i = 0; i < table.items.length; i ++) { 62 | var item = table.items[i]; 63 | 64 | if (item.getFieldValue('age') > 24 ) { 65 | item.setFieldValue('age', 25) 66 | .setFieldBackground('age', 'green') 67 | .setFieldNote('age', 'Happy 25 th birthday') 68 | .commit() 69 | } 70 | } 71 | } 72 | 73 | ``` 74 | 75 | 76 | --- 77 | 78 | If the Item object have a method that is not in our API yet, you can always get the Range object for any given line or field and access every methods available to the GAS Range object documented here: https://developers.google.com/apps-script/reference/spreadsheet/range 79 | 80 | 81 | ```javascript 82 | 83 | function getItemRanges() { 84 | var table = Sheetfu.getTable('people', 1); 85 | 86 | for (var i = 0; i < table.items.length; i++) { 87 | var item = table.items[i]; 88 | var lineRange = item.getLineRange(); 89 | var ageRange = item.getFieldRange('age'); 90 | } 91 | } 92 | 93 | ``` 94 | 95 | --- 96 | 97 | Every examples above assume that the target sheet only contains the table data. In many cases, we have more complex sheets that contains multiple mini grid/tables. 98 | Sheetfu can easily handle this situation by creating a table from a Range object instead of a sheet name. The submitted Range object must contain the header on its first line. 99 | 100 | 101 | ```javascript 102 | 103 | function getItemRanges() { 104 | var peopleRange = SpreadsheetApp().getSheetByName('people').getRange(1, 1, 20, 3); 105 | var animalRange = SpreadsheetApp().getSheetByName('people').getRange(60, 60, 10, 5); 106 | 107 | var peopleTable = new Sheetfu.Table(peopleRange); 108 | var animalTable = new Sheetfu.Table(animalRange); 109 | 110 | 111 | // Alternatively you can create a table by using a named Range. 112 | var table = Sheetfu.getTableByName('people_named_range'); 113 | } 114 | 115 | ``` 116 | 117 | --- 118 | 119 | If you have a field that you know is a unique value for every item (like an ID, email, etc...), 120 | you can create a table index to have very fast lookup if you want to search by ID. 121 | 122 | 123 | Let's take the following table as an example. We consider the email column to have unique values. 124 | 125 | | email | first_name | last_name | age | 126 | | --- | ---------- | --------- | --- | 127 | | philippe@gmail.com | Philippe | Oger | 36 | 128 | | guillem@gmail.com | Guillem | Orpinell | 25 | 129 | | john@gmail.com | John | Doe | 32 | 130 | | jane@gmail.com | Jane | Doe | 32 | 131 | 132 | 133 | 134 | ```javascript 135 | 136 | function lookingForPhilippe() { 137 | 138 | // THE OLD WAY (very slow) 139 | var table = Sheetfu.getTable('people', 1); 140 | var philippe = table.select({'email': 'philippe@gmail.com'}).first(); 141 | 142 | // THE NEW WAY 143 | // we tell Sheetfu to create an index with the 'email' field 144 | var table = Sheetfu.getTable('people', 1, 'email'); 145 | var philippe = table.getItemById('philippe@gmail.com'); 146 | 147 | // Also work when you create a table with the Table Object 148 | var range = SpreadsheetApp().getSheetByName('people').getRange(1, 1, 20, 4); 149 | var indexField = 'email'; 150 | var table = new Sheetfu.Table(range, indexField); 151 | var philippe = table.getItemById('philippe@gmail.com'); 152 | } 153 | 154 | ``` 155 | 156 | If you have a table of 20,000 lines, and you have to do make multiple lookups within the same process, performance will improve by orders of magnitude. 157 | 158 | 159 | ### Some comments/caveats: 160 | 161 | * You must not have duplicate fields in your header (columns with same field name). 162 | * The range used for creating a Table object must contain the header in the first row. 163 | * The Table object takes all the sheet data in memory, you can then manipulate, query it as you wish, but this will not change the data on the sheet until you commit the data. 164 | * You can commit Item or Table objects. No need to commit items if you plan on committing your table. You usually do one or the other. 165 | 166 | 167 | 168 | 169 | 170 | ### Installation 171 | 172 | 173 | You can use this code in 2 ways: 174 | * GIT clone this repo and create your own app script file using this code. Be aware that you will not need to precede function and object with 'Sheetfu' as shown in examples above.' 175 | * Access it as an app script library from the app script editor (recommended). 176 | * Go to Resources > Libraries ... 177 | * In the 'Add a library' placeholder, add the following key: 1N8BGDNX4N64WP4HRjsnZJNwBx2UrAbc_DPZKYwFnVxqzeJdqEJQuCBSv 178 | * 'Sheetfu' should be prompted. Select the last version. 179 | * You can then access the library functions and objects by starting to type Sheetfu and the auto-completion should be triggered.. 180 | 181 | -------------------------------------------------------------------------------- /item.gs: -------------------------------------------------------------------------------- 1 | /** 2 | * Constructor for an item in a Table object. 3 | * @param {Number} i: id/order of the item in the Table frame. Start at 0 (first item in grid). 4 | * @param {Range} range: the grid range the item is from. 5 | * @param {Array} header: The header array. 6 | * @constructor 7 | */ 8 | function Item(i, header, row, column, sheet) { 9 | this.fields = {}; 10 | 11 | this.table = {}; 12 | this.table.header = header; 13 | this.table.row = row; 14 | this.table.column = column; 15 | this.table.sheet = sheet; 16 | 17 | this.i = i; 18 | this.authorizedToCommit = true; 19 | } 20 | 21 | /** 22 | * Method to add a new field to the item, given a value, note, background, formula and font color. 23 | * @param {String} label: The name of the field. 24 | * @param {String|Number|Date} value: The value from a cell. 25 | * @param {String} note: The note from a cell. 26 | * @param {String} background: The background color of a cell (can be string for basic colors or hex code string). 27 | * @param {String} formula: The R1C1 format formula. 28 | * @param {String} font: The font color. 29 | */ 30 | Item.prototype.addField = function(label, value, note, background, formula, font) { 31 | this.fields[label] = {"value": value, "note": note, "background": background, "formula": formula, "font": font}; 32 | for (var param in this.fields[label]) { 33 | if (this.fields[label][param] === undefined) { 34 | this.fields[label][param] = ""; 35 | } 36 | } 37 | }; 38 | 39 | /** 40 | * Method to convert the item into a JS object, with its attributes being the header fields of the item. 41 | * @return {Object} itemObject: The object with each of the header/fieldValue pairs of the item. 42 | */ 43 | Item.prototype.toObject = function() { 44 | var self = this; 45 | return this.table.header.reduce( function(acc, headerField) { 46 | var fieldValue = self.getFieldValue(headerField); 47 | acc[headerField] = fieldValue; 48 | return acc; 49 | }, {}); 50 | }; 51 | 52 | /** 53 | * Commit a single item line in spreadsheet if the items order has not been changed since instantiating the grid. 54 | */ 55 | Item.prototype.commit = function () { 56 | if (!(this.authorizedToCommit)) { 57 | throw "Forbidden to commit this item. The order of the grid it is associated to has changed or it has been deleted." 58 | } 59 | 60 | var rowValues = []; 61 | var rowNotes = []; 62 | var rowBackgrounds = []; 63 | var rowWraps = []; 64 | var rowFontColors = []; 65 | 66 | for (var j = 0; j < this.table.header.length; j++) { 67 | var field = this.table.header[j]; 68 | var value = this.getFieldValue(field); 69 | var formula = this.getFieldFormula(field); 70 | 71 | (formula)? rowValues.push(formula) : rowValues.push(value); 72 | rowNotes.push(this.getFieldNote(field)); 73 | rowBackgrounds.push(this.getFieldBackground(field)); 74 | rowWraps.push(false); 75 | rowFontColors.push(this.getFieldFontColor(field)) 76 | } 77 | 78 | var lineRange = this.getLineRange(); 79 | lineRange.setValues([rowValues]); 80 | lineRange.setNotes([rowNotes]); 81 | lineRange.setBackgrounds([rowBackgrounds]); 82 | lineRange.setWraps([rowWraps]); 83 | lineRange.setFontColors([rowFontColors]); 84 | }; 85 | 86 | 87 | /** 88 | * Commit a whole item values. Disregarded other dimensions. 89 | */ 90 | Item.prototype.commitValues = function () { 91 | if (!(this.authorizedToCommit)) { 92 | throw "Forbidden to commit this item. The order of the grid it is associated to has changed or it has been deleted." 93 | } 94 | 95 | var rowValues = []; 96 | 97 | for (var j = 0; j < this.table.header.length; j++) { 98 | var field = this.table.header[j]; 99 | var value = this.getFieldValue(field); 100 | var formula = this.getFieldFormula(field); 101 | 102 | (formula)? rowValues.push(formula) : rowValues.push(value); 103 | } 104 | 105 | var lineRange = this.getLineRange(); 106 | lineRange.setValues([rowValues]); 107 | }; 108 | 109 | 110 | /** 111 | * Commit a whole item backgrounds. Disregarded other dimensions. 112 | */ 113 | Item.prototype.commitBackgrounds = function () { 114 | if (!(this.authorizedToCommit)) { 115 | throw "Forbidden to commit this item. The order of the grid it is associated to has changed." 116 | } 117 | var rowBackgrounds = []; 118 | for (var j = 0; j < this.table.header.length; j++) { 119 | var field = this.table.header[j]; 120 | var background = this.getFieldBackground(field); 121 | rowBackgrounds.push(background) 122 | } 123 | var lineRange = this.getLineRange(); 124 | lineRange.setBackgrounds([rowBackgrounds]); 125 | }; 126 | 127 | 128 | /** 129 | * Commit a single item field in spreadsheet if the items order has not been changed since instantiating the grid. 130 | * @param {String} field: the field of the item to commit in spreadsheet. 131 | */ 132 | Item.prototype.commitField = function (field) { 133 | if (!(this.authorizedToCommit)) { 134 | throw "Forbidden to commit this item field. The order of the grid it is associated to has changed or it has been deleted." 135 | } 136 | var cellRange = this.getFieldRange(field); 137 | if (this.getFieldFormula(field)) { 138 | cellRange.setValue(this.getFieldFormula(field)); 139 | } else { 140 | cellRange.setValue(this.getFieldValue(field)); 141 | } 142 | 143 | cellRange.setNote(this.getFieldNote(field)); 144 | cellRange.setBackground(this.getFieldBackground(field)); 145 | cellRange.setWrap(false); 146 | cellRange.setFontColor(this.getFieldFontColor(field)); 147 | }; 148 | 149 | 150 | /** 151 | * Commit a single item field value in spreadsheet if the items order has not been changed since instantiating the grid. 152 | * @param {String} field: the field of the item to commit the value from, in spreadsheet. 153 | */ 154 | Item.prototype.commitFieldValue = function (field) { 155 | if (!(this.authorizedToCommit)) { 156 | throw "Forbidden to commit this item field. The order of the grid it is associated to has changed or it has been deleted." 157 | } 158 | var cellRange = this.getFieldRange(field); 159 | if (this.getFieldFormula(field)) { 160 | cellRange.setValue(this.getFieldFormula(field)); 161 | } else { 162 | cellRange.setValue(this.getFieldValue(field)); 163 | } 164 | }; 165 | 166 | 167 | /** 168 | * Get the line range of the item in the spreadsheet it is from. 169 | * @return {Range} line: The line range. 170 | */ 171 | Item.prototype.getLineRange = function () { 172 | var headerOffset = 1; 173 | var rangePositionOffset = this.table.row; 174 | var row = this.i + headerOffset + rangePositionOffset; 175 | var column = this.table.column; 176 | var sheet = this.table.sheet; 177 | return sheet.getRange(row, column, 1, this.table.header.length); 178 | }; 179 | 180 | 181 | /** 182 | * Get the cell range of a given field of the item. 183 | * @param {string} field: A field string. 184 | * @return {Number} line: The line number. 185 | */ 186 | Item.prototype.getFieldRange = function (field) { 187 | var columnIndexOffset = 1; // columns starts at 1. 188 | var columnField = this.table.header.indexOf(field) + columnIndexOffset; 189 | return this.getLineRange().getCell(1, columnField); 190 | }; 191 | 192 | 193 | 194 | /** 195 | * Method to get the value of a given field. 196 | * @param {String} field: The name of the field. 197 | */ 198 | Item.prototype.getFieldValue = function(field) { 199 | var fieldParams = this.fields[field]; 200 | if(!fieldParams) { 201 | var error = "The field '" + field + 202 | "' cannot be found in the Table located in '"+ this.table.sheet.getSheetName() + 203 | "' sheet.\nCheck if the field exists, it's properly written and it's included in the Table range."; 204 | throw error; 205 | } 206 | return fieldParams["value"]; 207 | }; 208 | 209 | 210 | /** 211 | * Method to set a value for a given field. 212 | * @param {String} field: The name of the field. 213 | * @param {String|Number|Date} value: The value to set. 214 | */ 215 | Item.prototype.setFieldValue = function(field, value) { 216 | if(!this.fields[field]) { 217 | var error = "The field '" + field + 218 | "' cannot be found in the Table located in '"+ this.table.sheet.getSheetName() + 219 | "' sheet.\nCheck if the field exists, it's properly written and it's included in the Table range."; 220 | throw error; 221 | } 222 | this.fields[field]["value"] = value; 223 | this.fields[field]["formula"] = ''; 224 | return this; 225 | }; 226 | 227 | 228 | /** 229 | * Method to get note for a given field. 230 | * @param {String} field: The name of the field. 231 | */ 232 | Item.prototype.getFieldNote = function(field) { 233 | return this.fields[field]["note"]; 234 | }; 235 | 236 | 237 | /** 238 | * Method to set note for a given field. 239 | * @param {String} field: The name of the field. 240 | * @param {String} note: The note to set. 241 | */ 242 | Item.prototype.setFieldNote = function(field, note) { 243 | this.fields[field]["note"] = note; 244 | return this 245 | }; 246 | 247 | 248 | /** 249 | * Method to get background for a given field. 250 | * @param {String} field: The name of the field. 251 | */ 252 | Item.prototype.getFieldBackground = function(field) { 253 | return this.fields[field]["background"]; 254 | }; 255 | 256 | 257 | /** 258 | * Method to set background for a given field. 259 | * @param {String} field: The name of the field. 260 | * @param {String} background: The background to set (color string or hex code string). 261 | */ 262 | Item.prototype.setFieldBackground = function(field, background) { 263 | this.fields[field]["background"] = background; 264 | return this; 265 | }; 266 | 267 | 268 | /** 269 | * Method to set background on the whole item. 270 | * @param {String} color: The name or hex of the color. 271 | */ 272 | Item.prototype.setBackground = function(color) { 273 | for (var i = 0; i < this.table.header.length; i++) { 274 | var field = this.table.header[i]; 275 | this.fields[field]["background"] = color; 276 | } 277 | return this; 278 | }; 279 | 280 | 281 | /** 282 | * Method to set font color on the whole item. 283 | * @param {String} color: The name or hex of the color. 284 | */ 285 | Item.prototype.setFontColor = function(color) { 286 | for (var i = 0; i < this.table.header.length; i++) { 287 | var field = this.table.header[i]; 288 | this.fields[field]["font"] = color; 289 | } 290 | return this; 291 | }; 292 | 293 | 294 | /** 295 | * Method to get formula for a given field. 296 | * @param {String} field: The name of the field. 297 | */ 298 | Item.prototype.getFieldFormula = function(field) { 299 | return this.fields[field]["formula"] 300 | }; 301 | 302 | /** 303 | * Method to set formula for a given field. 304 | * @param {String} field: The name of the field. 305 | * @param {String} formula: The formula to set (must start with "="). 306 | */ 307 | Item.prototype.setFieldFormula = function(field, formula) { 308 | this.fields[field]["formula"] = formula; 309 | return this; 310 | }; 311 | 312 | 313 | /** 314 | * Method to get font color for a given field. 315 | * @param {String} field: The name of the field. 316 | */ 317 | Item.prototype.getFieldFontColor = function(field) { 318 | return this.fields[field]["font"]; 319 | }; 320 | 321 | 322 | /** 323 | * Method to set font color for a given field. 324 | * @param {String} field: The name of the field. 325 | * @param {String} fontColor: The font color to set. 326 | */ 327 | Item.prototype.setFieldFontColor = function(field, fontColor) { 328 | this.fields[field]["font"] = fontColor; 329 | return this; 330 | }; 331 | 332 | 333 | /** 334 | * Method to get the cell range for a specific field. 335 | * @param {String} field: The name of the field. 336 | * @return {Range} the cell range of the field. 337 | */ 338 | Item.prototype.getFieldRange = function(field) { 339 | var fieldIndex = this.table.header.indexOf(field); 340 | return this.getLineRange().getCell(1, fieldIndex + 1); 341 | }; 342 | 343 | -------------------------------------------------------------------------------- /table.gs: -------------------------------------------------------------------------------- 1 | /** 2 | * Function to create a Table Object for a whole sheet 3 | * @param {string} sheetName: Name of the sheet to create a Table from 4 | * @param {number} headerRow: Row number where the header is. 5 | * @param {String} indexField: Field name you want to create an index with (commonly for ID field for fast lookup). 6 | * @returns {Table} 7 | */ 8 | function getTable(sheetName, headerRow, indexField) { 9 | if (!headerRow) { 10 | headerRow = 1; 11 | } 12 | var sheet = SpreadsheetApp.getActiveSpreadsheet().getSheetByName(sheetName); 13 | var numberOfRows = sheet.getLastRow() - headerRow + 1; 14 | var tableRange = sheet.getRange(headerRow, 1, numberOfRows, sheet.getLastColumn()); 15 | return new Table(tableRange, indexField); 16 | } 17 | 18 | 19 | /** 20 | * Function to create a Table Object from a Named Range. The range should contain a header in the first row. 21 | * Named ranges are ranges that have associated string aliases. 22 | * They can be viewed and edited via the Sheets UI under the Data > Named ranges... menu. 23 | * @param {string} namedRange: Name of the range to create a Table from 24 | * @param {String} indexField: Field name you want to create an index with (commonly for ID field for fast lookup). 25 | * @returns {Table} 26 | */ 27 | function getTableByName(namedRange, indexField) { 28 | var ss = SpreadsheetApp.getActiveSpreadsheet(); 29 | var tableRange = ss.getRangeByName(namedRange); 30 | if (tableRange == null) { 31 | throw 'Oops! Error creating a table with the named range '+namedRange+'. It might not exist or it is misspelled.' 32 | } 33 | return new Table(tableRange, indexField); 34 | } 35 | 36 | 37 | /** Constructor which create a Table object to query data, get and post. Object to use when rows in sheet are not uniquely 38 | * identifiable (no id). Use Table Class for DB-like queries instead (when unique id exist for each row). 39 | * @param {Range} gridRange: a range object from Google spreadsheet. First row of range must be the headers. 40 | * @param {String} indexField: Field name you want to create an index with (commonly for ID field for fast lookup). 41 | * @constructor 42 | */ 43 | function Table(gridRange, indexField) { 44 | 45 | this.gridRange = trimRangeRows(gridRange); 46 | this.initialGridRange = this.gridRange; 47 | this.header = this.getHeader(); 48 | this.items = this.initiateItems(); 49 | 50 | this.indexField = indexField; 51 | if (this.indexField !== undefined) { 52 | this.index = this.getIndex(indexField); 53 | } 54 | } 55 | 56 | 57 | /** 58 | * Function to trim the rows of a range. The range should contain a header in the first row. 59 | * @param {Range} range: a range object from Google spreadsheet. First row of range must be the headers. 60 | * @returns {Range} 61 | */ 62 | function trimRangeRows(range) { 63 | var values = range.getValues(); 64 | for (var rowIndex = values.length - 1; rowIndex >= 0; rowIndex--) { 65 | if (values[rowIndex].join('') !== '') { 66 | break; 67 | } 68 | } 69 | return range.offset(rowOffset=0, columnOffset=0, numRows=rowIndex+1); 70 | } 71 | 72 | 73 | /** 74 | * Method to extract headers of a grid. 75 | * @return {Array} The list of labels. 76 | */ 77 | Table.prototype.getHeader = function () { 78 | return this.gridRange.getValues()[0]; 79 | }; 80 | 81 | 82 | /** 83 | * Method to create an index as a hash table for a given field. Make sure the field guarantees unique values. Perfect for IDs. 84 | * @return {Object} Hash table in the format {fieldIndex : TableItem} 85 | */ 86 | Table.prototype.getIndex = function (indexField) { 87 | var index = {}; 88 | for (var i = 0; i < this.items.length; i++) { 89 | var key = this.items[i].getFieldValue(indexField); 90 | index[key] = this.items[i]; 91 | } 92 | return index; 93 | }; 94 | 95 | 96 | /** 97 | * Method to extract data from the grid range as Item objects (using header labels). 98 | * @return {Item[]} List of Item objects. 99 | * The i attribute is the index of the object in the list of Table.items (starting at 0) (not the line in spreadsheet). 100 | */ 101 | Table.prototype.initiateItems = function() { 102 | var rawValues = this.gridRange.getValues().slice(1); // we disregard first row because it is header. 103 | var rawNotes = this.gridRange.getNotes().slice(1); 104 | var rawBackgrounds = this.gridRange.getBackgrounds().slice(1); 105 | var rawFormulas = this.gridRange.getFormulasR1C1().slice(1); 106 | var rawFontColors = this.gridRange.getFontColors().slice(1); 107 | 108 | var items = new GridArray(); 109 | 110 | for (var row = 0; row < rawValues.length; row++) { 111 | var parseItem = new Item(row, this.header, this.gridRange.getRow(), this.gridRange.getColumn(), this.gridRange.getSheet()); 112 | for (var column = 0; column < this.header.length; column++) { 113 | var label = this.header[column]; 114 | parseItem.addField( 115 | label=label, 116 | value=rawValues[row][column], 117 | note=rawNotes[row][column], 118 | background=rawBackgrounds[row][column], 119 | formula=rawFormulas[row][column], 120 | font=rawFontColors[row][column] 121 | ) 122 | } 123 | items.push(parseItem); 124 | } 125 | return items; 126 | }; 127 | 128 | 129 | /** 130 | * Method to commit the items into the associated sheet (regardless if number of items have changed). 131 | */ 132 | Table.prototype.commit = function() { 133 | var dataToSend = this.getGridData(); 134 | var itemsRange = this.getItemsRange(); 135 | this.cleanInitialGrid(); 136 | this.initialGridRange = this.gridRange; 137 | if(itemsRange !== undefined) { 138 | itemsRange.setValues(dataToSend['values']); 139 | itemsRange.setNotes(dataToSend['notes']); 140 | itemsRange.setBackgrounds(dataToSend['backgrounds']); 141 | itemsRange.setWraps(dataToSend['wraps']); 142 | itemsRange.setFontColors(dataToSend['fonts']); 143 | } 144 | }; 145 | 146 | 147 | /** 148 | * Method to commit the items values into the associated sheet (regardless if number of items have changed). 149 | */ 150 | Table.prototype.commitValues = function() { 151 | var values = this.getGridValues(); 152 | var itemsRange = this.getItemsRange(); 153 | this.cleanInitialGrid(); 154 | this.initialGridRange = this.gridRange; 155 | if(itemsRange !== undefined) { 156 | itemsRange.setValues(values); 157 | } 158 | }; 159 | 160 | /** 161 | * Method to get the new Range for the items, based on lenght of Table.items. 162 | * @return {Range} object of the items range. {Undefined} if the items range is empty. 163 | */ 164 | Table.prototype.getItemsRange = function() { 165 | // We need to check that items is not empty, since Sheet.getRange() throws an exception if numRows or numColumns are 0. 166 | if(this.items.length === 0) { 167 | return undefined; 168 | } 169 | var row = this.gridRange.getRow() + 1; // +1 to disregard header row 170 | var column = this.gridRange.getColumn(); 171 | var sheet = this.gridRange.getSheet(); 172 | return sheet.getRange(row, column, this.items.length, this.header.length); 173 | }; 174 | 175 | /** 176 | * Method to create both values and notes 2D arrays from grid items. 177 | * @return {object} with attributes "values" and "notes". 178 | */ 179 | Table.prototype.getGridData = function() { 180 | var values = []; 181 | var notes = []; 182 | var backgrounds = []; 183 | var wraps = []; 184 | var fontColors =[]; 185 | 186 | for (var i = 0; i < this.items.length; i++) { 187 | var rowValues = []; 188 | var rowNotes = []; 189 | var rowBackgrounds = []; 190 | var rowWraps = []; 191 | var rowFontColors = []; 192 | var item = this.items[i]; 193 | 194 | for (var j = 0; j < this.header.length; j++) { 195 | var field = this.header[j]; 196 | var value = item.getFieldValue(field); 197 | var formula = item.getFieldFormula(field); 198 | 199 | (formula)? rowValues.push(formula) : rowValues.push(value); 200 | rowNotes.push(item.getFieldNote(field)); 201 | rowBackgrounds.push(item.getFieldBackground(field)); 202 | rowWraps.push(false); 203 | rowFontColors.push(item.getFieldFontColor(field)) 204 | } 205 | values.push(rowValues); 206 | notes.push(rowNotes); 207 | backgrounds.push(rowBackgrounds); 208 | wraps.push(rowWraps); 209 | fontColors.push(rowFontColors) 210 | } 211 | return {"values": values, "notes": notes, "backgrounds": backgrounds, "wraps": wraps, "fonts": fontColors} 212 | }; 213 | 214 | 215 | /** 216 | * Method to create 2D array of the values of every grid items. 217 | * @return {Array[]} The values 2D array. 218 | */ 219 | Table.prototype.getGridValues = function() { 220 | var values = []; 221 | 222 | for (var i = 0; i < this.items.length; i++) { 223 | var rowValues = []; 224 | var item = this.items[i]; 225 | 226 | for (var j = 0; j < this.header.length; j++) { 227 | var field = this.header[j]; 228 | var value = item.getFieldValue(field); 229 | var formula = item.getFieldFormula(field); 230 | 231 | (formula)? rowValues.push(formula) : rowValues.push(value); 232 | } 233 | values.push(rowValues); 234 | } 235 | return values 236 | }; 237 | 238 | /** 239 | * Method to query rows from a Table, given exact match attributes. 240 | * @param {Array} criteria: an array used as filter as an AND of ORs (see CNF). 241 | * @return {Item[]} List of Item objects matching the given criteria. 242 | */ 243 | Table.prototype.select = function(criteria) { 244 | var queryItems = new Selector(this, criteria) 245 | .evaluate() 246 | .getQueryItems(); 247 | 248 | return queryItems; 249 | }; 250 | 251 | 252 | /** 253 | * Method to update one item within items grid. 254 | * @param {object} item: an item from items. 255 | * The index value is the value where the item is in the Table.items array. Needed to be able to change the value in Table. 256 | */ 257 | Table.prototype.update = function(item) { 258 | this.items[item['_i']] = item; 259 | }; 260 | 261 | 262 | /** 263 | * Method to update many items within items grid. 264 | * @param {object[]} manyItems: list of objects to update. 265 | */ 266 | Table.prototype.updateMany = function(manyItems) { 267 | for (var i = 0; i < this.items.length; i++) { 268 | var index = manyItems[i]['_i']; 269 | this.items[index] = manyItems[i]; 270 | } 271 | }; 272 | 273 | 274 | 275 | /** 276 | * Method to delete items from the items grid based on a selection criteria. 277 | * @param {object} filteredObject: Criteria to select the items to delete. See documentation of the "select" method. 278 | */ 279 | Table.prototype.deleteSelection = function(filterObject) { 280 | var selectionToDelete = this.select(filterObject); 281 | return this.deleteMany(selectionToDelete); 282 | }; 283 | 284 | /** 285 | * Method to delete several items from the items grid. 286 | * @param {list} itemList: A list of items that you wish to delete 287 | * Take into account that deleting items re-calculates the indices of all items with higher index inside Table.items. 288 | */ 289 | Table.prototype.deleteMany = function(itemList) { 290 | if(itemList.length === this.items.length) 291 | { 292 | return this.deleteAll(); 293 | } 294 | 295 | // First we sort the list of items to delete by index 296 | itemList.sort(function(firstItem, secondItem) { 297 | // Compare the i attribute of both items 298 | if(firstItem.i < secondItem.i) return -1; 299 | if(firstItem.i > secondItem.i) return 1; 300 | return 0; 301 | }); 302 | 303 | // Now we iterate the sorted list in inverse order and delete the items 304 | var indexReduction = itemList.length; 305 | var lastDeletedIndex = this.items.length - 1; 306 | for(var i = itemList.length - 1; i >= 0; i--) 307 | { 308 | var itemToDelete = itemList[i]; 309 | itemToDelete.authorizedToCommit = false; // To prevent the user from commiting deleted items. 310 | var indexToDelete = itemToDelete.i; 311 | if(indexToDelete >= this.items.length) { 312 | throw "One of the items specified to delete has an out of bounds index."; 313 | } 314 | this.items.splice(indexToDelete, 1); 315 | 316 | // For every item to delete, we will recalculate the indexes from the item that was deleted 317 | // to the last item before the previously deleted index. 318 | for (var k = indexToDelete; k < lastDeletedIndex - 1; k++) { 319 | var itemToUpdateIndex = this.items[k]; 320 | // We reduce the index by as many items are left to delete 321 | itemToUpdateIndex.i = itemToUpdateIndex.i - indexReduction; 322 | } 323 | lastDeletedIndex = indexToDelete; 324 | indexReduction--; 325 | } 326 | 327 | // Reduce the gridRange by as many rows as were deleted 328 | this.gridRange = this.gridRange.offset(0, 0, this.gridRange.getHeight() - itemList.length, this.gridRange.getWidth()); 329 | }; 330 | 331 | 332 | /** 333 | * Method to delete one item from the items grid. 334 | * @param {item} item: An item from this.items that you wish to delete 335 | * Take into account that deleting an item re-calculates the indices of all items with higher index inside Table.items. 336 | */ 337 | Table.prototype.deleteOne = function(item) { 338 | return this.deleteMany([item]); 339 | }; 340 | 341 | 342 | /** 343 | * Method to delete all items withing the items grid. 344 | */ 345 | Table.prototype.deleteAll = function() { 346 | this.items = new GridArray(); 347 | this.gridRange = this.getHeaderRange(); 348 | }; 349 | 350 | 351 | /** 352 | * Method to delete all rows inside the initial grid. 353 | */ 354 | Table.prototype.cleanInitialGrid = function() { 355 | this.initialGridRange.clear({contentsOnly: true, skipFilteredRows: true}); 356 | var header = this.getHeaderRange(); 357 | header.setValues([this.header]); 358 | }; 359 | 360 | 361 | /** 362 | * Method to get the range of the header. 363 | * @return {Range} headerRange: the range of the header only (basically top row). 364 | */ 365 | Table.prototype.getHeaderRange = function() { 366 | var row = this.gridRange.getRow(); 367 | var column = this.gridRange.getColumn(); 368 | var sheet = this.gridRange.getSheet(); 369 | return sheet.getRange(row, column, 1, this.header.length) 370 | }; 371 | 372 | 373 | /** 374 | * Method to add a new item into the Table. Add the item also to index if there is an index. 375 | * @param {object} input_item: an object item containing only values, or an instance of Item. Field must be matching header values. 376 | */ 377 | Table.prototype.add = function(input_item) { 378 | 379 | var raw_item = input_item; 380 | if(input_item instanceof Item) { 381 | raw_item = {} 382 | for (var field in input_item.fields) { 383 | raw_item[field] = input_item.getFieldValue(field); 384 | } 385 | } 386 | 387 | var newItem = new Item(this.items.length, this.header, this.gridRange.getRow(), this.gridRange.getColumn(), this.gridRange.getSheet()); 388 | 389 | for (var i = 0; i < this.header.length; i++) { 390 | var label = this.header[i]; 391 | if (raw_item[label] === undefined) { 392 | raw_item[label] = ""; 393 | } 394 | newItem.addField(field=label, value=raw_item[label]); 395 | } 396 | this.items.push(newItem); 397 | 398 | // Increase the gridRange by one row 399 | this.gridRange = this.gridRange.offset(0, 0, this.gridRange.getHeight()+1, this.gridRange.getWidth()); 400 | 401 | if (this.index !== undefined) { 402 | var indexId = newItem.getFieldValue(this.indexField); 403 | this.index[indexId] = newItem; 404 | } 405 | return newItem; 406 | }; 407 | 408 | 409 | /** 410 | * Method to sort Table.items for a given field/key/label value. 411 | * Only works for numbers and date fields. 412 | * @param {string} key: the key label that we need to sort items from. 413 | * @param {boolean} ascending: If True it sorts ascending, if false, it sort descending. 414 | * @return {object[]} items: Table.items attribute. 415 | */ 416 | Table.prototype.sortBy = function(key, ascending) { 417 | 418 | this.items.sort(function(a, b) { 419 | var timeStampA = Date.parse(a.getFieldValue(key)); 420 | var timeStampB = Date.parse(b.getFieldValue(key)); 421 | if (!isNaN(timeStampA) && !isNaN(timeStampB)) { 422 | var dateA = new Date(a.getFieldValue(key)); 423 | var keyA = dateA.getTime(); 424 | var dateB = new Date(b.getFieldValue(key)); 425 | var keyB = dateB.getTime(); 426 | } else { 427 | var keyA = a.getFieldValue(key); 428 | var keyB = b.getFieldValue(key); 429 | } 430 | 431 | // Compare the 2 keys 432 | if(keyA < keyB) return -1; 433 | if(keyA > keyB) return 1; 434 | return 0; 435 | 436 | }); 437 | 438 | if (ascending === false) { 439 | this.items.reverse() 440 | } 441 | 442 | // updating '_i' 443 | for (var i = 0; i < this.items.length; i++) { 444 | this.items[i].i = i; 445 | this.items[i].authorizedToCommit = false; // to prevent committing lines when order has changed. 446 | } 447 | return this.items 448 | }; 449 | 450 | 451 | /** 452 | * Method to clear background colors on every items. 453 | * @return {Range}: The range of items which had their background cleaned. {Undefined} if the items range is empty. 454 | */ 455 | Table.prototype.clearBackgrounds = function () { 456 | var itemRange = this.getItemsRange(); 457 | if(itemRange !== undefined) { 458 | return itemRange.clearFormat(); 459 | } 460 | else { 461 | return undefined; 462 | } 463 | }; 464 | 465 | 466 | /** 467 | * Get an item from the table by its ID (assuming an index field was given when creating the table). 468 | */ 469 | Table.prototype.getItemById = function (valueId) { 470 | return this.index[valueId] 471 | }; 472 | 473 | 474 | /** 475 | * Vertical lookup. Searches down the index field of a table (assuming an index field was given when creating the table) 476 | * for a criteria and returns the value of a specified field in the item found. 477 | */ 478 | Table.prototype.getFieldValueById = function (field, valueId) { 479 | var itemById = this.getItemById(valueId); 480 | if(itemById) { 481 | return itemById.getFieldValue(field); 482 | } else { 483 | return undefined; 484 | } 485 | } 486 | 487 | 488 | /** 489 | * Method to return only distinct different values in a field. 490 | */ 491 | Table.prototype.distinct = function(field) { 492 | var list = []; 493 | for (var i = 0; i < this.items.length; i++) { 494 | list.push(this.items[i].getFieldValue(field)); 495 | } 496 | // It filters the list to return an array with the unique values 497 | var unique = list.filter(function(value, index, self) { 498 | return self.indexOf(value) === index; 499 | }); 500 | return unique 501 | } 502 | 503 | 504 | /** 505 | * Function to clone an object and simulate inheritance. 506 | */ 507 | function cloneObj(obj) { 508 | function F() { } 509 | F.prototype = obj; 510 | return new F(); 511 | } 512 | 513 | 514 | /** 515 | * SubArray class constructor to have more ORM like methods to the arrays used in the Table class. 516 | */ 517 | function GridArray() {} 518 | GridArray.prototype = cloneObj(Array.prototype); 519 | 520 | 521 | /** 522 | * Method to return only the first result of an array. Useful when result of selection. 523 | */ 524 | GridArray.prototype.first = function() { 525 | if (this.length === 0) { 526 | return undefined; 527 | } 528 | return this[0]; 529 | }; 530 | 531 | 532 | /** 533 | * Method to return the first x results of an array. Useful when result of selection. 534 | */ 535 | GridArray.prototype.limit = function(x) { 536 | if(this.length > x) { 537 | return this.slice(0, x); 538 | } else { 539 | return this; 540 | } 541 | }; 542 | 543 | --------------------------------------------------------------------------------