├── Code.gs ├── README.md └── appscript.json /Code.gs: -------------------------------------------------------------------------------- 1 | function onInstall(e) { 2 | onOpen(e); 3 | } 4 | 5 | function onOpen(e) { 6 | var ui = SpreadsheetApp.getUi(); 7 | var addOnMenu = ui.createAddonMenu(); 8 | addOnMenu.addItem(' 🔢 Get Stats', 'updateMenu') 9 | .addToUi(); 10 | 11 | // This always leads to `needEdit` function with no error on browser console 12 | // if (e && e.authMode == ScriptApp.AuthMode.NONE) { 13 | // addOnMenu.addItem(' 🔢 Get Stats', 'needEdit') 14 | // .addToUi(); 15 | // } else { 16 | // addOnMenu.addItem(' 🔢 Get Stats', 'updateMenu') 17 | // .addToUi(); 18 | // } 19 | 20 | } 21 | 22 | function needEdit() { 23 | var ui = SpreadsheetApp.getUi(); 24 | ui.alert("You need 'Edit' access to trigger this add-on"); 25 | } 26 | 27 | function wbStats() { 28 | var start = new Date().getTime(); 29 | var ss = SpreadsheetApp.getActiveSpreadsheet(); 30 | var activeSheet = ss.getActiveSheet(); 31 | var allSheets = ss.getSheets(); 32 | var title = 'Workbook Statistics'; 33 | 34 | // Current Sheet Data 35 | 36 | ss.toast(" 🔥 Fetching: Current Sheet > Sheet Name...", title, -1); 37 | var sheetNameCS = activeSheet.getName(); 38 | Logger.log("Current Sheet > Sheet Name " + sheetNameCS); 39 | 40 | if (activeSheet.getType() == 'GRID') { 41 | var dataRange = activeSheet.getDataRange(); 42 | var dataValues = dataRange.getValues(); 43 | var formulaRanges = dataRange.getFormulas(); 44 | 45 | ss.toast(" 🔥 Fetching: Current Sheet > End of Sheet...", title, -1); 46 | var endOfSheetCS; 47 | try { 48 | endOfSheetCS = activeSheet.getRange(activeSheet.getLastRow(), activeSheet.getLastColumn()).getA1Notation(); 49 | } catch (e) { 50 | endOfSheetCS = 'A1'; 51 | } 52 | Logger.log("Current Sheet > End of Sheet " + endOfSheetCS); 53 | 54 | ss.toast(" 🔥 Fetching: Current Sheet > Cells with Data...", title, -1); 55 | var cellsWithDataCS = dataValues.map(function(sub) { 56 | return sub.reduce(function(prev, cur) { 57 | return prev + (!!cur); 58 | }, 0); 59 | }).reduce(function(a,b){ 60 | return a + b; 61 | }, 0); 62 | Logger.log("Current Sheet > Cells with Data " + cellsWithDataCS); 63 | 64 | ss.toast(" 🔥 Fetching: Current Sheet > Named Ranges...", title, -1); 65 | var namedRangesCS = activeSheet.getNamedRanges().length; 66 | Logger.log("Current Sheet > Named Ranges " + namedRangesCS); 67 | 68 | ss.toast(" 🔥 Fetching: Current Sheet > Pivot Tables...", title, -1); 69 | var pivotTablesCS = activeSheet.getPivotTables().length; 70 | Logger.log("Current Sheet > Pivot Tables " + pivotTablesCS); 71 | 72 | ss.toast(" 🔥 Fetching: Current Sheet > Formulas...", title, -1); 73 | var formulasCS = formulaRanges.map(function(sub) { 74 | return sub.reduce(function(prev, cur) { 75 | return prev + (!!cur); 76 | }, 0); 77 | }).reduce(function(a,b){ 78 | return a + b 79 | }, 0); 80 | Logger.log("Current Sheet > Formulas " + formulasCS); 81 | } else { 82 | endOfSheetCS = 'N/A'; 83 | cellsWithDataCS = 'N/A'; 84 | namedRangesCS = 'N/A'; 85 | pivotTablesCS = 'N/A'; 86 | formulasCS = 'N/A'; 87 | } 88 | 89 | ss.toast(" 🔥 Fetching: Current Sheet > Charts...", title, -1); 90 | var chartsCS = activeSheet.getCharts().length; 91 | Logger.log("Current Sheet > Charts " + chartsCS); 92 | 93 | // Workbook data 94 | 95 | ss.toast(" 🔥 Fetching: Workbook > Sheets...", title, -1); 96 | var totalSheetsWB = allSheets.length; 97 | Logger.log("Workbook > Sheets " + totalSheetsWB); 98 | 99 | ss.toast(" 🔥 Fetching: Workbook > Cells with Data...", title, -1); 100 | var cellsWithDataWB = 0; 101 | for (var i = 0; i < allSheets.length; i++) { 102 | var sheet = allSheets[i]; 103 | if (sheet.getType() == 'GRID') { 104 | var currentSheetValues = ss.getSheetByName(sheet.getName()).getDataRange().getValues(); 105 | var currentSheetData = currentSheetValues.map(function(sub) { 106 | return sub.reduce(function(prev, cur) { 107 | return prev + (!!cur); 108 | }, 0); 109 | }).reduce(function(a,b){ 110 | return a + b; 111 | }, 0); 112 | cellsWithDataWB = cellsWithDataWB + currentSheetData; 113 | } 114 | } 115 | Logger.log("Workbook > Cells with Data " + cellsWithDataWB); 116 | 117 | ss.toast(" 🔥 Fetching: Workbook > Named Ranges...", title, -1); 118 | var namedRangesWB = allSheets.map(function(sheet) { 119 | return ss.getSheetByName(sheet.getName()).getNamedRanges().length; 120 | }).reduce(function(a,b){ 121 | return a + b; 122 | }, 0); 123 | Logger.log("Workbook > Named Ranges " + namedRangesWB) 124 | 125 | ss.toast(" 🔥 Fetching: Workbook > Pivot Tables...", title, -1); 126 | var pivotTablesWB = allSheets.filter(function(sheet) { 127 | return ss.getSheetByName(sheet.getName()).getType() == 'GRID'; 128 | }).map(function(sheet) { 129 | return ss.getSheetByName(sheet.getName()).getPivotTables().length; 130 | }).reduce(function(a,b){ 131 | return a + b; 132 | }, 0); 133 | Logger.log("Workbook > Pivot Tables " + pivotTablesWB); 134 | 135 | ss.toast(" 🔥 Fetching: Workbook > Formulas...", title, -1); 136 | var formulasWB = 0; 137 | for (var i = 0; i < allSheets.length; i++) { 138 | var sheet = allSheets[i]; 139 | if (sheet.getType() == 'GRID') { 140 | var currentSheetValues = ss.getSheetByName(sheet.getName()).getDataRange().getFormulas(); 141 | var currentSheetFormulas = currentSheetValues.map(function(sub) { 142 | return sub.reduce(function(prev, cur) { 143 | return prev + (!!cur); 144 | }, 0); 145 | }).reduce(function(a,b){ 146 | return a + b; 147 | }, 0); 148 | formulasWB = formulasWB + currentSheetFormulas; 149 | } 150 | } 151 | Logger.log("Workbook > Formulas " + formulasWB); 152 | 153 | ss.toast(" 🔥 Fetching: Workbook > Charts...", title, -1); 154 | var chartsWB = allSheets.map(function(sheet) { 155 | return ss.getSheetByName(sheet.getName()).getCharts().length; 156 | }).reduce(function(a,b){ 157 | return a + b 158 | }, 0); 159 | Logger.log("Workbook > Charts " + chartsWB); 160 | 161 | var end = new Date().getTime(); 162 | var diffSec = (end - start)/1000; 163 | var duration = diffSec > 60 ? (diffSec / 60).toFixed(2) + " mins." : diffSec.toFixed(2) + " secs."; 164 | 165 | ss.toast(" 🎉 It took " + duration + " to fetch all details. Updating Add-on Menu...", title, 10); 166 | return { 167 | "sheetNameCS": sheetNameCS, 168 | "endOfSheetCS": endOfSheetCS, 169 | "cellsWithDataCS": cellsWithDataCS, 170 | "namedRangesCS": namedRangesCS, 171 | "pivotTablesCS": pivotTablesCS, 172 | "formulasCS": formulasCS, 173 | "chartsCS": chartsCS, 174 | "totalSheetsWB": totalSheetsWB, 175 | "cellsWithDataWB": cellsWithDataWB, 176 | "namedRangesWB": namedRangesWB, 177 | "pivotTablesWB": pivotTablesWB, 178 | "formulasWB": formulasWB, 179 | "chartsWB": chartsWB 180 | } 181 | } 182 | 183 | function noAction() { 184 | var ss = SpreadsheetApp.getActiveSpreadsheet(); 185 | ss.toast(" 🥑 No Action Taken. Please click 'Refresh All' to update stats.", 'Workbook Statistics', -1); 186 | } 187 | 188 | function updateMenu() { 189 | var ui = SpreadsheetApp.getUi(); 190 | var addOnMenu = ui.createAddonMenu(); 191 | var data = wbStats(); 192 | addOnMenu 193 | .addSubMenu(ui.createMenu(' ⚡ Combined') 194 | .addItem(' 📄 Current Sheet', 'noAction') 195 | .addItem(' ☞ Sheet Name: ' + data.sheetNameCS, 'noAction') 196 | .addItem(' ☞ End of Sheet: ' + data.endOfSheetCS, 'noAction') 197 | .addItem(' ☞ Cells with Data: ' + data.cellsWithDataCS, 'noAction') 198 | .addItem(' ☞ Named Ranges: ' + data.namedRangesCS, 'noAction') 199 | .addItem(' ☞ Pivot Tables: ' + data.pivotTablesCS, 'noAction') 200 | .addItem(' ☞ Formulas: ' + data.formulasCS, 'noAction') 201 | .addItem(' ☞ Charts: ' + data.chartsCS, 'noAction') 202 | .addSeparator() 203 | .addItem(' 📓 Workbook', 'noAction') 204 | .addItem(' ☞ Sheets: ' + data.totalSheetsWB, 'noAction') 205 | .addItem(' ☞ Cells with Data: ' + data.cellsWithDataWB, 'noAction') 206 | .addItem(' ☞ Named Ranges: ' + data.namedRangesWB, 'noAction') 207 | .addItem(' ☞ Pivot Tables: ' + data.pivotTablesWB, 'noAction') 208 | .addItem(' ☞ Formulas: ' + data.formulasWB, 'noAction') 209 | .addItem(' ☞ Charts: ' + data.chartsWB, 'noAction') 210 | .addSeparator() 211 | .addItem(' 🔄 Refresh All', 'updateMenu')) 212 | .addSeparator() 213 | .addSubMenu(ui.createMenu(' ⚡ Current Sheet') 214 | .addItem(' ☞ Sheet Name: ' + data.sheetNameCS, 'noAction') 215 | .addItem(' ☞ End of Sheet: ' + data.endOfSheetCS, 'noAction') 216 | .addItem(' ☞ Cells with Data: ' + data.cellsWithDataCS, 'noAction') 217 | .addItem(' ☞ Named Ranges: ' + data.namedRangesCS, 'noAction') 218 | .addItem(' ☞ Pivot Tables: ' + data.pivotTablesCS, 'noAction') 219 | .addItem(' ☞ Formulas: ' + data.formulasCS, 'noAction') 220 | .addItem(' ☞ Charts: ' + data.chartsCS, 'noAction') 221 | .addItem(' 🔄 Refresh Current Sheet', 'updateMenu')) 222 | .addSeparator() 223 | .addSubMenu(ui.createMenu(' ⚡ Workbook') 224 | .addItem(' ☞ Sheets: ' + data.totalSheetsWB, 'noAction') 225 | .addItem(' ☞ Cells with Data: ' + data.cellsWithDataWB, 'noAction') 226 | .addItem(' ☞ Named Ranges: ' + data.namedRangesWB, 'noAction') 227 | .addItem(' ☞ Pivot Tables: ' + data.pivotTablesWB, 'noAction') 228 | .addItem(' ☞ Formulas: ' + data.formulasWB, 'noAction') 229 | .addItem(' ☞ Charts: ' + data.chartsWB, 'noAction') 230 | .addItem(' 🔄 Refresh Workbook', 'updateMenu')) 231 | .addSeparator() 232 | .addItem(' 🔄 Refresh All', 'updateMenu') 233 | .addToUi(); 234 | } 235 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # workbook-statistics 2 | Google Spreadsheet add-on to get stats for your current active sheet and the entire workbook in one place. 3 | -------------------------------------------------------------------------------- /appscript.json: -------------------------------------------------------------------------------- 1 | { 2 | "timeZone": "Asia/Kolkata", 3 | "dependencies": { 4 | }, 5 | "oauthScopes": [ 6 | "https://www.googleapis.com/auth/spreadsheets.currentonly" 7 | ], 8 | "exceptionLogging": "STACKDRIVER" 9 | } 10 | --------------------------------------------------------------------------------