├── LICENCE ├── README.md ├── RangeListApp.js ├── appsscript.json └── images ├── sample_fig1.png ├── sample_fig2.png ├── sample_fig3.png ├── sample_fig4.png ├── sample_fig5.png ├── sample_fig6.png ├── sample_fig7.png └── sample_fig8.png /LICENCE: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | Copyright (c) 2018 Kanshi TANAIKE 3 | 4 | Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions: 5 | 6 | The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software. 7 | 8 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. 9 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | RangeListApp 2 | ===== 3 | 4 | 5 | [![MIT License](http://img.shields.io/badge/license-MIT-blue.svg?style=flat)](LICENCE) 6 | 7 | 8 | # Overview 9 | **RangeListApp is a GAS library for retrieving, putting and replacing values for Spreadsheet by a range list with a1Notation using Google Apps Script (GAS).** 10 | 11 | 12 | 13 | # Description 14 | There is [Class RangeList](https://developers.google.com/apps-script/reference/spreadsheet/range-list) as one of classes for Spreadsheet. There is ``setValue(value)`` in Class RangeList as a method. ``setValue(value)`` puts ``value`` to the cells of range list. Recently, when I used this method, I noticed that the following situations what I want cannot be achieved. 15 | 16 | - Put the different values to each cell of the range list. 17 | - Retrieve values from each cell of the range list. 18 | - Replace values of each cell of the range list using regex. 19 | - Use various sheets to the range list. 20 | - Put checkbox to each cell of the range list. 21 | 22 | Although these might be able to be used by the future update, I created this library, because I wanted to achieve them soon. If this library is also useful for you, I'm glad. 23 | 24 | 25 | # Library's project key 26 | ~~~ 27 | 1L44xvi-AsdwbYgqeb63e2i-7PpC01Mt-1fgNO2HpTTvAHPMU1HteAIsY 28 | ~~~ 29 | 30 | 31 | # How to install 32 | 1. [Install RangeListApp library](https://developers.google.com/apps-script/guides/libraries). 33 | - Library's project key is **``1L44xvi-AsdwbYgqeb63e2i-7PpC01Mt-1fgNO2HpTTvAHPMU1HteAIsY``**. 34 | 1. [Enable Sheets API at Advanced Google services](https://developers.google.com/apps-script/guides/services/advanced#enabling_advanced_services). 35 | 36 | Installing is done! You can use RangeListApp. 37 | 38 | > At the first run of the script using library, the authorization screen is displayed. Please authorize it. By this, you can use Sheets API. This authorization is required to do for only the first run. 39 | 40 | ### If you are using the GAS project created before April 8, 2019, please enable Sheets API at API console as follows. 41 | 1. Enable Sheets API at API console 42 | - On script editor 43 | - Resources -> Cloud Platform project 44 | - View API console 45 | - At Getting started, click Enable APIs and get credentials like keys. 46 | - At left side, click Library. 47 | - At Search for APIs & services, input **Sheets API**. And click Sheets API. 48 | - Click Enable button. 49 | - If it has already been enabled, please don't turn off. 50 | 51 | # Methods 52 | | Methods | Return | Descriptions | 53 | |:------|:------|:------| 54 | | getValues() | Object | Retrieve values from each cell using range list. This works like [``getValues()`` of Class Range](https://developers.google.com/apps-script/reference/spreadsheet/range#getValues()). | 55 | | getDisplayValues() | Object | Retrieve display values from each cell using range list. This works like [``getDisplayValues()`` of Class Range](https://developers.google.com/apps-script/reference/spreadsheet/range#getDisplayValues()). | 56 | | getFormulas() | Object | Retrieve formulas from each cell using range list. This works like [``getFormulas()`` of Class Range](https://developers.google.com/apps-script/reference/spreadsheet/range#getformulas). | 57 | | setValues(values) | Object | Put values to cells of range list. This works like [``setValues()`` of Class Range](https://developers.google.com/apps-script/reference/spreadsheet/range#setvaluesvalues). Inputted the range list is returned. | 58 | | replaceValues(regex, value) | Object | Replace values of cells of range list using regex. Inputted the range list is returned. | 59 | | replaceFormulas(regex, value) | Object | Replace formulas of cells of range list using regex. Inputted the range list is returned. | 60 | | setCheckBox(values) | Object | Put checkbox to cells of range list. Inputted the range list is returned. | 61 | | [expandA1Notations(rangeList)](#expandA1Notations) | Object | Expand a1Notation. For example, ``A1:C2`` is expanded to ``"A1","B1","C1","A2","B2","C2"``. | 62 | 63 | I would like to add more methods in the future. 64 | 65 | # Usage 66 | ## 1. getValues(), getDisplayValues(), getFormulas() 67 | These methods retrieve values from each cell using range list. 68 | 69 | As the samples, it uses the following sheets. 70 | 71 | ![](images/sample_fig1.png) 72 | 73 | ![](images/sample_fig2.png) 74 | 75 | In this sample script, the values of ``"A1", "B2", "C3:D4", "sheet2!A3", "sheet2!B2:B5", "sheet2!D6:E7"`` are retrieved using getValues(). 76 | 77 | - When the active sheet is "Sheet1", "A1", "B2" and "C3:D4" mean "Sheet1!A1", "Sheet1!B2" and "Sheet1!C3:D4", respectively. 78 | - When you want to retrieve the values of other sheet, you can use "sheet2!A3", "sheet2!B2:B5" and "sheet2!D6:E7". 79 | - **getFormulas() and getDisplayValues() can also be used like getValues()**. The difference is the result. 80 | - getFormulas() retrieves the formula of each cell. This works like [getFormulas() of class Range](https://developers.google.com/apps-script/reference/spreadsheet/range#getformulas). 81 | - getDisplayValues() retrieves the display value of each cell. This works like [getDisplayValues() of class Range](https://developers.google.com/apps-script/reference/spreadsheet/range#getDisplayValues()). 82 | 83 | #### Sample script 84 | ~~~javascript 85 | var rangeList = ["A1", "B2", "C3:D4", "sheet2!A3", "sheet2!B2:B5", "sheet2!D6:E7"]; 86 | var spreadsheet = SpreadsheetApp.getActiveSpreadsheet(); 87 | var r = RangeListApp.getSpreadsheet(spreadsheet).getRangeList(rangeList).getValues(); 88 | 89 | // var r = RangeListApp.getSpreadsheet(spreadsheet).getRangeList(rangeList).getFormulas(); 90 | // var r = RangeListApp.getSpreadsheet(spreadsheet).getRangeList(rangeList).getDisplayValues(); 91 | ~~~ 92 | 93 | #### Result 94 | These values can be retrieved by one API call. All values are 2 dimensional array. 95 | 96 | ~~~json 97 | [ 98 | {"range":"Sheet1!A1","values":[["sheet1_A1"]]}, 99 | {"range":"Sheet1!B2","values":[["sheet1_B2"]]}, 100 | {"range":"Sheet1!C3:D4","values":[["sheet1_C3","sheet1_D3"],["sheet1_C4","sheet1_D4"]]}, 101 | {"range":"sheet2!A3","values":[["sheet2_A3"]]}, 102 | {"range":"sheet2!B2:B5","values":[["sheet2_B2"],[],[],["sheet2_B5"]]}, 103 | {"range":"sheet2!D6:E7","values":[["sheet2_D6","sheet2_E6"],["sheet2_D7"]]} 104 | ] 105 | ~~~ 106 | 107 | ## 2. setValues() 108 | This method put values to each cell using range list. 109 | 110 | #### Sample script 111 | ~~~javascript 112 | var rangeList = ["A1", "B2", "C3:D4", "sheet2!A3", "sheet2!B2:B5", "sheet2!D6:E7"]; 113 | var values = ["sample1", 123, "sample2", "=sum(B2:B5)", "=ROW() * 2", true]; 114 | var spreadsheet = SpreadsheetApp.getActiveSpreadsheet(); 115 | var r = RangeListApp.getSpreadsheet(spreadsheet).getRangeList(rangeList).setValues(values); 116 | ~~~ 117 | 118 | - Lengths of ``rangeList`` and ``values`` are required to be the same. For example, 2nd index of ``rangeList`` (``"B2"``) is corresponding to the 2nd index of ``values`` (``123``). 119 | - When the range including several cells is set to ``rangeList`` like ``"C3:D4"``, ``"sample2"`` is put to all cells of range. 120 | - When you want to put a formula, you can use it like ``"=sum(B2:B5)"``. This library checks the top letter of each element in ``values``. When it is ``=``, the element is put as a formula. 121 | - For example, when you want to put ``=ROW() * 2`` as a string, you can put it by giving ``==ROW() * 2``. 122 | - When ``==`` is used for the top letter of formula, the formula is put as a string. When it is put, ``==`` is converted to ``=``. 123 | - setValues() returns rangeList. 124 | - For above sample script, when ``var values = "sample";`` is used, "sample" is put to all cells of "rangeList". This works like "setValue(value)" of [Class RangeList](https://developers.google.com/apps-script/reference/spreadsheet/range-list). 125 | 126 | #### Result 127 | ![](images/sample_fig3.png) 128 | 129 | ![](images/sample_fig4.png) 130 | 131 | 132 | ## 3. replaceValues(), replaceFormulas() 133 | These methods replace values of each cell using range list by regex. 134 | 135 | #### Sample script 136 | ~~~javascript 137 | var rangeList = ["A1", "B2", "C3:D4"]; 138 | var spreadsheet = SpreadsheetApp.getActiveSpreadsheet(); 139 | var regex = new RegExp("[a-d]"); 140 | var value = "foo"; 141 | var r = RangeListApp.getSpreadsheet(spreadsheet).getRangeList(rangeList).replaceValues(regex, value); 142 | ~~~ 143 | 144 | - In this library, it uses [String.prototype.replace()](https://developer.mozilla.org/en-US/docs/Web/JavaScript/Reference/Global_Objects/String/replace) for replacing values. So you can use regexp and substr for ``regex``. 145 | - In these methods, ``regex`` and ``value`` which can be used is one value, respectively. 146 | - When ``replaceFormulas()`` instead of ``replaceValues()`` is used, it can replace formulas in each cell. 147 | 148 | #### Result 149 | ![](images/sample_fig5.png) 150 | 151 | ![](images/sample_fig6.png) 152 | 153 | 154 | ## 4. setCheckBox() 155 | This method puts checkbox to each cell using range list. 156 | 157 | #### Sample script 158 | ~~~javascript 159 | var rangeList = ["A1", "B2", "C3:D4"]; 160 | var values = [[], [], ["foo", "bar"]]; 161 | var spreadsheet = SpreadsheetApp.getActiveSpreadsheet(); 162 | var r = RangeListApp.getSpreadsheet(spreadsheet).getRangeList(rangeList).setCheckBox(values); 163 | ~~~ 164 | 165 | - Basic usage is the same with ``setValues()``. 166 | - In the sample script, ``["foo", "bar"]`` of ``values`` means ``true`` and ``false``, respectively. 167 | 168 | #### Result 169 | ##### From : 170 | ![](images/sample_fig7.png) 171 | 172 | ##### To : 173 | ![](images/sample_fig8.png) 174 | 175 | 176 | 177 | ## 5. expandA1Notations() 178 | ~~~javascript 179 | var rangeList = ["A1:E3", "B10:W13", "EZ5:FA8", "AAA1:AAB3"]; 180 | var r = RangeListApp.expandA1Notations(rangeList); 181 | ~~~ 182 | 183 | - This is one of methods of Class RangeListApp. 184 | - Methods of "columnToLetter" and "letterToColumn" are from [Stackoverflow](https://stackoverflow.com/a/21231012/7108653). When I saw the thread, I could notice about this method. Thank you so much. 185 | 186 | #### Result 187 | ~~~ 188 | [ 189 | ["A1","B1","C1","D1","E1","A2","B2","C2","D2","E2","A3","B3","C3","D3","E3"], 190 | ["B10","C10","D10","E10","F10","G10","H10","I10","J10","K10","L10","M10","N10","O10","P10","Q10","R10","S10","T10","U10","V10","W10","B11","C11","D11","E11","F11","G11","H11","I11","J11","K11","L11","M11","N11","O11","P11","Q11","R11","S11","T11","U11","V11","W11","B12","C12","D12","E12","F12","G12","H12","I12","J12","K12","L12","M12","N12","O12","P12","Q12","R12","S12","T12","U12","V12","W12","B13","C13","D13","E13","F13","G13","H13","I13","J13","K13","L13","M13","N13","O13","P13","Q13","R13","S13","T13","U13","V13","W13"], 191 | ["EZ5","FA5","EZ6","FA6","EZ7","FA7","EZ8","FA8"], 192 | ["AAA1","AAB1","AAA2","AAB2","AAA3","AAB3"] 193 | ] 194 | ~~~ 195 | 196 | 197 | ----- 198 | 199 | 200 | # Licence 201 | [MIT](LICENCE) 202 | 203 | 204 | # Author 205 | [Tanaike](https://tanaikech.github.io/about/) 206 | 207 | If you have any questions and commissions for me, feel free to tell me. 208 | 209 | 210 | # Update History 211 | * v1.0.0 (July 27, 2018) 212 | 213 | 1. Initial release. 214 | 215 | * v1.0.1 (September 13, 2018) 216 | 217 | 1. [New method of "expandA1Notations"](#expandA1Notations) was added. This method can expand the a1Notations. For example, ``A1:C2`` is expanded to ``"A1","B1","C1","A2","B2","C2"``. 218 | 219 | [TOP](#TOP) 220 | -------------------------------------------------------------------------------- /RangeListApp.js: -------------------------------------------------------------------------------- 1 | /** 2 | * GitHub https://github.com/tanaikech/RangeListApp
3 | * @param {Object} spreadsheet Instance of a Spreadsheet. 4 | * @return {RangeListApp} 5 | */ 6 | function getSpreadsheet(spreadsheet) { 7 | this.spreadsheet = spreadsheet; 8 | return this 9 | } 10 | 11 | /** 12 | * @param {Object} rangeList Range list created by 1 dimensional array. 13 | * @return {RangeListApp} 14 | */ 15 | function getRangeList(rangeList) { 16 | this.rangeList = rangeList; 17 | return this 18 | } 19 | 20 | /** 21 | * setValues method for RangeListApp.
22 | * @param {Object} values Values (number, string and bool) for putting to Spreadsheet. This is one dimensional array. 23 | * @return {Object} Return Object 24 | */ 25 | function setValues(values) { 26 | var rl = new RangeListApp(this.rangeList, this.spreadsheet); 27 | return rl.setValues(values); 28 | } 29 | 30 | /** 31 | * replaceValues method for RangeListApp.
32 | * @param {Object} regex Regex which is used for replacing. 33 | * @param {Object} value Value for replacing. 34 | * @return {Object} Return Object 35 | */ 36 | function replaceValues(regex, value) { 37 | var rl = new RangeListApp(this.rangeList, this.spreadsheet); 38 | return rl.replaceValues(regex, value); 39 | } 40 | 41 | /** 42 | * replaceFormulas method for RangeListApp.
43 | * @param {Object} regex Regex which is used for replacing. 44 | * @param {Object} value Value for replacing. 45 | * @return {Object} Return Object 46 | */ 47 | function replaceFormulas(regex, value) { 48 | var rl = new RangeListApp(this.rangeList, this.spreadsheet); 49 | return rl.replaceFormulas(regex, value); 50 | } 51 | 52 | /** 53 | * setCheckBox method for RangeListApp.
54 | * @param {Object} values String values which are used for true and false. This is one dimensional array. The element 0 and 1 mean true and false. 55 | * @return {Object} Return Object 56 | */ 57 | function setCheckBox(values) { 58 | var rl = new RangeListApp(this.rangeList, this.spreadsheet); 59 | return rl.setCheckBox(values); 60 | } 61 | 62 | /** 63 | * getFormulas method for RangeListApp.
64 | * @return {Object} Return Object 65 | */ 66 | function getFormulas() { 67 | var rl = new RangeListApp(this.rangeList, this.spreadsheet); 68 | return rl.getFormulas(); 69 | } 70 | 71 | /** 72 | * getDisplayValues method for RangeListApp.
73 | * @return {Object} Return Object 74 | */ 75 | function getDisplayValues() { 76 | var rl = new RangeListApp(this.rangeList, this.spreadsheet); 77 | return rl.getDisplayValues(); 78 | } 79 | 80 | /** 81 | * getValues method for RangeListApp.
82 | * @return {Object} Return Object 83 | */ 84 | function getValues() { 85 | var rl = new RangeListApp(this.rangeList, this.spreadsheet); 86 | return rl.getValues(); 87 | } 88 | 89 | /** 90 | * expandA1Notations method for RangeListApp.
91 | * @param {Object} rangeList Range list created by 1 dimensional array. 92 | * @return {Object} Return Object 93 | */ 94 | function expandA1Notations(rangeList) { 95 | var rl = new RangeListApp(null, null, "expandA1Notations"); 96 | return rl.expandA1Notations(rangeList); 97 | } 98 | 99 | // SpreadsheetApp.getActiveSpreadsheet(); // For scope 100 | // Methods of "columnToLetter" and "letterToColumn" are from "https://stackoverflow.com/a/21231012/7108653" 101 | ; 102 | (function(r) { 103 | var RangeListApp; 104 | RangeListApp = (function() { 105 | var addQuery, columnToLetter, createReqForSetChkeckBox, createReqForSetValues, createReqRepeatCellChkBox, createReqRepeatCellUpdate, createReqSingleCellChkBox, createReqSingleCellUpdate, doExpandA1Notations, fetch, getDataValues, getidentification, letterToColumn, parseRange, replaceValues, setDataValues, setReplacedValues; 106 | 107 | RangeListApp.name = "RangeListApp"; 108 | 109 | function RangeListApp(rangeList_, spreadsheet_, func_) { 110 | if (func_ == null) { 111 | if (!rangeList_ || rangeList_.length === 0) { 112 | throw new Error("rangeList was not found."); 113 | } 114 | if (!Array.isArray(rangeList_)) { 115 | throw new Error("rangeList was not an array."); 116 | } 117 | if (!spreadsheet_) { 118 | throw new Error("spreadsheet was not found."); 119 | } 120 | this.rangeList = rangeList_; 121 | this.url = "https://sheets.googleapis.com/v4/spreadsheets/"; 122 | this.headers = { 123 | Authorization: 'Bearer ' + ScriptApp.getOAuthToken() 124 | }; 125 | if (!spreadsheet_ || spreadsheet_ === void 0) { 126 | this.spreadsheet = SpreadsheetApp.getActiveSpreadsheet(); 127 | } else { 128 | this.spreadsheet = spreadsheet_; 129 | } 130 | this.sheet = SpreadsheetApp.getActiveSheet(); 131 | this.spreadsheetId = this.spreadsheet.getId(); 132 | this.sheetId = this.sheet.getSheetId(); 133 | } 134 | } 135 | 136 | RangeListApp.prototype.setValues = function(values) { 137 | return setDataValues.call(this, "values", values); 138 | }; 139 | 140 | RangeListApp.prototype.replaceValues = function(regex, value) { 141 | var src, values; 142 | src = getDataValues.call(this, "UNFORMATTED_VALUE"); 143 | values = replaceValues.call(this, src, regex, value); 144 | return setReplacedValues.call(this, values); 145 | }; 146 | 147 | RangeListApp.prototype.replaceFormulas = function(regex, value) { 148 | var src, values; 149 | src = getDataValues.call(this, "FORMULA"); 150 | values = replaceValues.call(this, src, regex, value); 151 | return setReplacedValues.call(this, values); 152 | }; 153 | 154 | RangeListApp.prototype.setCheckBox = function(values) { 155 | return setDataValues.call(this, "checkbox", values); 156 | }; 157 | 158 | RangeListApp.prototype.getValues = function() { 159 | return getDataValues.call(this, "UNFORMATTED_VALUE"); 160 | }; 161 | 162 | RangeListApp.prototype.getDisplayValues = function() { 163 | return getDataValues.call(this, "FORMATTED_VALUE"); 164 | }; 165 | 166 | RangeListApp.prototype.getFormulas = function() { 167 | return getDataValues.call(this, "FORMULA"); 168 | }; 169 | 170 | RangeListApp.prototype.expandA1Notations = function(rangeList) { 171 | return doExpandA1Notations.call(this, rangeList); 172 | }; 173 | 174 | replaceValues = function(src, regex, value) { 175 | if (src == null) { 176 | throw new Error("Range is not found."); 177 | } 178 | if (value == null) { 179 | throw new Error("Value for replacing was not found."); 180 | } 181 | if (regex == null) { 182 | throw new Error("Regex was not found."); 183 | } 184 | src.forEach(function(e, i) { 185 | return src[i].values = e.values.map(function(f) { 186 | return f.map(function(g) { 187 | if (typeof g === "string") { 188 | return g.replace(regex, value); 189 | } else { 190 | return g; 191 | } 192 | }); 193 | }); 194 | }); 195 | return src; 196 | }; 197 | 198 | setReplacedValues = function(values) { 199 | var obj, req; 200 | obj = { 201 | data: values, 202 | valueInputOption: "USER_ENTERED" 203 | }; 204 | req = [ 205 | { 206 | method: "post", 207 | url: this.url + this.spreadsheetId + "/values:batchUpdate", 208 | headers: this.headers, 209 | contentType: "application/json", 210 | payload: JSON.stringify(obj), 211 | muteHttpExceptions: true 212 | } 213 | ]; 214 | fetch.call(this, req); 215 | return this.rangeList; 216 | }; 217 | 218 | setDataValues = function(ident, values) { 219 | var addCols, addRows, defCol, defRow, maxCol, maxRow, req, requests, rngList, setData; 220 | if (!values || values.length === 0) { 221 | throw new Error("Values was not found."); 222 | } 223 | defRow = 0; 224 | defCol = 0; 225 | maxRow = 0; 226 | maxCol = 0; 227 | rngList = parseRange.call(this, this.rangeList); 228 | addRows = []; 229 | addCols = []; 230 | setData = rngList.map((function(_this) { 231 | return function(e, i) { 232 | var col, initCol, initRow, numCols, numRows, range, row, sheet, sheetId, temp, val; 233 | sheet = null; 234 | sheetId = ""; 235 | range = null; 236 | if (e.length === 1) { 237 | sheet = _this.sheet; 238 | sheetId = _this.sheetId; 239 | range = _this.sheet.getRange(e[0]); 240 | } else { 241 | sheet = _this.spreadsheet.getSheetByName(e[0]); 242 | sheetId = sheet.getSheetId(); 243 | range = _this.sheet.getRange(e[1]); 244 | } 245 | defRow = sheet.getMaxRows(); 246 | defCol = sheet.getMaxColumns(); 247 | maxRow = defRow; 248 | maxCol = defCol; 249 | initRow = range.getRow(); 250 | initCol = range.getColumn(); 251 | numRows = range.getNumRows(); 252 | numCols = range.getNumColumns(); 253 | row = initRow; 254 | col = initCol; 255 | if (numRows > 1) { 256 | row = initRow + numRows - 1; 257 | } 258 | if (numCols > 1) { 259 | col = initCol + numCols - 1; 260 | } 261 | maxRow = maxRow < row ? row : maxRow; 262 | maxCol = maxCol < col ? col : maxCol; 263 | if (defRow !== maxRow) { 264 | temp = addRows.filter(function(e) { 265 | return e.appendDimension.sheetId === sheetId; 266 | }); 267 | if (temp.length === 0) { 268 | addRows.push({ 269 | appendDimension: { 270 | sheetId: sheetId, 271 | length: maxRow - defRow, 272 | dimension: "ROWS" 273 | } 274 | }); 275 | } else { 276 | if (temp[0].appendDimension.length < (maxRow - defRow)) { 277 | addRows.forEach(function(f, i) { 278 | if (f.appendDimension.sheetId === sheetId) { 279 | return addRows[i] = { 280 | appendDimension: { 281 | sheetId: sheetId, 282 | length: maxRow - defRow, 283 | dimension: "ROWS" 284 | } 285 | }; 286 | } 287 | }); 288 | } 289 | } 290 | } 291 | if (defCol !== maxCol) { 292 | temp = addCols.filter(function(e) { 293 | return e.appendDimension.sheetId === sheetId; 294 | }); 295 | if (temp.length === 0) { 296 | addCols.push({ 297 | appendDimension: { 298 | sheetId: sheetId, 299 | length: maxCol - defCol, 300 | dimension: "COLUMNS" 301 | } 302 | }); 303 | } else { 304 | if (temp[0].appendDimension.length < (maxCol - defCol)) { 305 | addCols.forEach(function(f, i) { 306 | if (f.appendDimension.sheetId === sheetId) { 307 | return addCols[i] = { 308 | appendDimension: { 309 | sheetId: sheetId, 310 | length: maxCol - defCol, 311 | dimension: "COLUMNS" 312 | } 313 | }; 314 | } 315 | }); 316 | } 317 | } 318 | } 319 | val = Array.isArray(values) ? values[i] : values; 320 | switch (ident) { 321 | case "values": 322 | return createReqForSetValues.call(_this, sheetId, initRow, initCol, numRows, numCols, val); 323 | case "checkbox": 324 | return createReqForSetChkeckBox.call(_this, sheetId, initRow, initCol, numRows, numCols, val); 325 | } 326 | }; 327 | })(this)); 328 | requests = []; 329 | if (addRows.length > 0) { 330 | Array.prototype.push.apply(requests, addRows); 331 | } 332 | if (addCols.length > 0) { 333 | Array.prototype.push.apply(requests, addCols); 334 | } 335 | Array.prototype.push.apply(requests, setData); 336 | req = [ 337 | { 338 | method: "post", 339 | url: this.url + this.spreadsheetId + ":batchUpdate", 340 | headers: this.headers, 341 | contentType: "application/json", 342 | payload: JSON.stringify({ 343 | requests: requests 344 | }), 345 | muteHttpExceptions: true 346 | } 347 | ]; 348 | fetch.call(this, req); 349 | return this.rangeList; 350 | }; 351 | 352 | createReqForSetValues = function(sheetId, initRow, initCol, numRows, numCols, val) { 353 | var identification, type; 354 | type = typeof val; 355 | identification = ""; 356 | if (type === "number" || type === "boolean") { 357 | identification = type; 358 | } else if (type === "string") { 359 | if (val[0] === "=" && val[1] !== "=") { 360 | identification = "formula"; 361 | } else if (val[0] === "=" && val[1] === "=") { 362 | identification = "string"; 363 | val = val.slice(1); 364 | } else { 365 | identification = type; 366 | } 367 | } else { 368 | identification = "string"; 369 | val = val.toString(); 370 | } 371 | if (numRows === 1 && numCols === 1) { 372 | return createReqSingleCellUpdate.call(this, identification, sheetId, initRow, initCol, val); 373 | } else { 374 | return createReqRepeatCellUpdate.call(this, identification, sheetId, initRow, initCol, numRows, numCols, val); 375 | } 376 | }; 377 | 378 | createReqForSetChkeckBox = function(sheetId, initRow, initCol, numRows, numCols, val) { 379 | if (numRows === 1 && numCols === 1) { 380 | return createReqSingleCellChkBox.call(this, sheetId, initRow, initCol, val); 381 | } else { 382 | return createReqRepeatCellChkBox.call(this, sheetId, initRow, initCol, numRows, numCols, val); 383 | } 384 | }; 385 | 386 | getDataValues = function(option) { 387 | var endpoint, query, req, res; 388 | query = { 389 | majorDimension: "ROWS", 390 | valueRenderOption: option, 391 | fields: "valueRanges(range,values)", 392 | ranges: this.rangeList 393 | }; 394 | endpoint = addQuery.call(this, this.url + this.spreadsheetId + "/values:batchGet", query); 395 | req = [ 396 | { 397 | method: "get", 398 | url: addQuery.call(this, this.url + this.spreadsheetId + "/values:batchGet", query), 399 | headers: this.headers, 400 | muteHttpExceptions: true 401 | } 402 | ]; 403 | res = fetch.call(this, req); 404 | return res.valueRanges; 405 | }; 406 | 407 | parseRange = function(rangeList) { 408 | return rangeList.reduce(function(res, e) { 409 | r = e.split("!").map(function(f) { 410 | return f.replace(/'/g, ""); 411 | }); 412 | res.push(Array.prototype.concat.apply([], r)); 413 | return res; 414 | }, []); 415 | }; 416 | 417 | createReqSingleCellUpdate = function(identification, sheetId, initRow, initCol, value) { 418 | var obj; 419 | obj = { 420 | "updateCells": { 421 | "range": { 422 | "sheetId": sheetId, 423 | "startRowIndex": initRow - 1, 424 | "endRowIndex": initRow, 425 | "startColumnIndex": initCol - 1, 426 | "endColumnIndex": initCol 427 | }, 428 | "rows": [ 429 | { 430 | "values": [ 431 | { 432 | userEnteredValue: {} 433 | } 434 | ] 435 | } 436 | ], 437 | "fields": "userEnteredValue" 438 | } 439 | }; 440 | getidentification.call(this, identification, obj.updateCells.rows[0].values[0].userEnteredValue, value); 441 | return obj; 442 | }; 443 | 444 | createReqRepeatCellUpdate = function(identification, sheetId, initRow, initCol, numRows, numCols, value) { 445 | var obj; 446 | obj = { 447 | "repeatCell": { 448 | "range": { 449 | "sheetId": sheetId, 450 | "startRowIndex": initRow - 1, 451 | "endRowIndex": initRow + numRows - 1, 452 | "startColumnIndex": initCol - 1, 453 | "endColumnIndex": initCol + numCols - 1 454 | }, 455 | "cell": { 456 | "userEnteredValue": {} 457 | }, 458 | "fields": "userEnteredValue" 459 | } 460 | }; 461 | getidentification.call(this, identification, obj.repeatCell.cell.userEnteredValue, value); 462 | return obj; 463 | }; 464 | 465 | createReqSingleCellChkBox = function(sheetId, initRow, initCol, value) { 466 | var obj; 467 | obj = { 468 | "updateCells": { 469 | "range": { 470 | "sheetId": sheetId, 471 | "startRowIndex": initRow - 1, 472 | "endRowIndex": initRow, 473 | "startColumnIndex": initCol - 1, 474 | "endColumnIndex": initCol 475 | }, 476 | "rows": [ 477 | { 478 | "values": [ 479 | { 480 | "dataValidation": { 481 | "condition": { 482 | "type": "BOOLEAN" 483 | } 484 | } 485 | } 486 | ] 487 | } 488 | ], 489 | "fields": "dataValidation" 490 | } 491 | }; 492 | if (value.length === 2) { 493 | obj.updateCells.rows[0].values[0].dataValidation.condition.values = [ 494 | { 495 | userEnteredValue: value[0] 496 | }, { 497 | userEnteredValue: value[1] 498 | } 499 | ]; 500 | } 501 | return obj; 502 | }; 503 | 504 | createReqRepeatCellChkBox = function(sheetId, initRow, initCol, numRows, numCols, value) { 505 | var obj; 506 | obj = { 507 | "repeatCell": { 508 | "range": { 509 | "sheetId": sheetId, 510 | "startRowIndex": initRow - 1, 511 | "endRowIndex": initRow + numRows - 1, 512 | "startColumnIndex": initCol - 1, 513 | "endColumnIndex": initCol + numCols - 1 514 | }, 515 | "cell": { 516 | "dataValidation": { 517 | "condition": { 518 | "type": "BOOLEAN" 519 | } 520 | } 521 | }, 522 | "fields": "dataValidation" 523 | } 524 | }; 525 | if (value.length === 2) { 526 | obj.repeatCell.cell.dataValidation.condition.values = [ 527 | { 528 | userEnteredValue: value[0] 529 | }, { 530 | userEnteredValue: value[1] 531 | } 532 | ]; 533 | } 534 | return obj; 535 | }; 536 | 537 | getidentification = function(identification, v, value) { 538 | switch (identification) { 539 | case "boolean": 540 | return v.boolValue = value; 541 | case "formula": 542 | return v.formulaValue = value; 543 | case "number": 544 | return v.numberValue = value; 545 | case "string": 546 | return v.stringValue = value; 547 | } 548 | }; 549 | 550 | addQuery = function(url_, obj_) { 551 | return url_ + Object.keys(obj_).reduce(function(p, e, i) { 552 | return p + (i === 0 ? "?" : "&") + (Array.isArray(obj_[e]) ? obj_[e].reduce(function(str, f, j) { 553 | return str + e + "=" + encodeURIComponent(f) + (j !== obj_[e].length - 1 ? "&" : ""); 554 | }, "") : e + "=" + encodeURIComponent(obj_[e])); 555 | }, ""); 556 | }; 557 | 558 | fetch = function(req) { 559 | var err, res; 560 | res = UrlFetchApp.fetchAll(req); 561 | err = res.filter(function(e) { 562 | return e.getResponseCode() !== 200; 563 | }); 564 | if (err.length > 0) { 565 | throw new Error(err.length + " errors occurred. ErrorMessage: " + err.toString()); 566 | return; 567 | } 568 | return JSON.parse(res[0].getContentText()); 569 | }; 570 | 571 | columnToLetter = function(column) { 572 | var letter, temp; 573 | temp = 0; 574 | letter = ""; 575 | while (column > 0) { 576 | temp = (column - 1) % 26; 577 | letter = String.fromCharCode(temp + 65) + letter; 578 | column = (column - temp - 1) / 26; 579 | } 580 | return letter; 581 | }; 582 | 583 | letterToColumn = function(letter) { 584 | var column, i, k, length, ref; 585 | column = 0; 586 | length = letter.length; 587 | for (i = k = 0, ref = length; 0 <= ref ? k < ref : k > ref; i = 0 <= ref ? ++k : --k) { 588 | column += (letter.charCodeAt(i) - 64) * Math.pow(26, length - i - 1); 589 | } 590 | return column; 591 | }; 592 | 593 | doExpandA1Notations = function(rangeList) { 594 | var reg; 595 | if (!Array.isArray(rangeList)) { 596 | throw new Error("Please give rangeList as one dimensional array."); 597 | } 598 | reg = new RegExp("([A-Z]+)([0-9]+)"); 599 | return rangeList.map(function(e) { 600 | var a1, i, j, k, l, obj, ref, ref1, ref2, ref3, rr, temp; 601 | a1 = e.split("!"); 602 | r = a1.length > 1 ? a1[1] : a1[0]; 603 | rr = r.split(":").map(function(f) { 604 | return f.toUpperCase().match(reg); 605 | }); 606 | obj = { 607 | startRowIndex: Number(rr[0][2]), 608 | endRowIndex: rr.length === 1 ? Number(rr[0][2]) + 1 : Number(rr[1][2]) + 1, 609 | startColumnIndex: letterToColumn.call(this, rr[0][1]), 610 | endColumnIndex: rr.length === 1 ? letterToColumn.call(this, rr[0][1]) + 1 : letterToColumn.call(this, rr[1][1]) + 1 611 | }; 612 | temp = []; 613 | for (i = k = ref = obj.startRowIndex, ref1 = obj.endRowIndex; ref <= ref1 ? k < ref1 : k > ref1; i = ref <= ref1 ? ++k : --k) { 614 | for (j = l = ref2 = obj.startColumnIndex, ref3 = obj.endColumnIndex; ref2 <= ref3 ? l < ref3 : l > ref3; j = ref2 <= ref3 ? ++l : --l) { 615 | temp.push(columnToLetter.call(this, j) + i); 616 | } 617 | } 618 | return temp; 619 | }); 620 | }; 621 | 622 | return RangeListApp; 623 | 624 | })(); 625 | return r.RangeListApp = RangeListApp; 626 | })(this); 627 | -------------------------------------------------------------------------------- /appsscript.json: -------------------------------------------------------------------------------- 1 | { 2 | "timeZone": "Asia/Tokyo", 3 | "dependencies": { 4 | }, 5 | "exceptionLogging": "STACKDRIVER" 6 | } 7 | -------------------------------------------------------------------------------- /images/sample_fig1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tanaikech/RangeListApp/008c2f3b466cbff4c0c12bf91f09dc52f04ba59d/images/sample_fig1.png -------------------------------------------------------------------------------- /images/sample_fig2.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tanaikech/RangeListApp/008c2f3b466cbff4c0c12bf91f09dc52f04ba59d/images/sample_fig2.png -------------------------------------------------------------------------------- /images/sample_fig3.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tanaikech/RangeListApp/008c2f3b466cbff4c0c12bf91f09dc52f04ba59d/images/sample_fig3.png -------------------------------------------------------------------------------- /images/sample_fig4.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tanaikech/RangeListApp/008c2f3b466cbff4c0c12bf91f09dc52f04ba59d/images/sample_fig4.png -------------------------------------------------------------------------------- /images/sample_fig5.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tanaikech/RangeListApp/008c2f3b466cbff4c0c12bf91f09dc52f04ba59d/images/sample_fig5.png -------------------------------------------------------------------------------- /images/sample_fig6.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tanaikech/RangeListApp/008c2f3b466cbff4c0c12bf91f09dc52f04ba59d/images/sample_fig6.png -------------------------------------------------------------------------------- /images/sample_fig7.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tanaikech/RangeListApp/008c2f3b466cbff4c0c12bf91f09dc52f04ba59d/images/sample_fig7.png -------------------------------------------------------------------------------- /images/sample_fig8.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tanaikech/RangeListApp/008c2f3b466cbff4c0c12bf91f09dc52f04ba59d/images/sample_fig8.png --------------------------------------------------------------------------------