commit
message
[ADDRESS] formula added and tested
author
Ben Vogt <[email protected]>
date
2017-09-09 15:17:07
stats
7 file(s) changed,
232 insertions(+),
5 deletions(-)
files
TODO.md
dist/Formulas/AllFormulas.js
dist/Formulas/Lookup.js
src/Formulas/AllFormulas.ts
src/Formulas/Lookup.ts
tests/Formulas/LookupTest.ts
tests/SheetFormulaTest.ts
1diff --git a/TODO.md b/TODO.md
2index 317b2cd..f2d42bb 100644
3--- a/TODO.md
4+++ b/TODO.md
5@@ -23,7 +23,6 @@ For example `=#N/A` should force an error to be thrown inside the cell.
6 Many of these formulas can be written by allowing the Sheet and Parser to return Cell objects in addition to primitive types. There are some memory issues with doing this. If a user calls something like `ISNA(A1:A99999)` we really only need the first cell. So we should return cell objects in some cases, but it would be easier in most cases to have context aware formulas, so if they need a cell, or a reference, we simply skip looking up a reference, and instead return a reference, or just a single cell. One way to do this would be to have formula functions, and then on the side have formula args. So before we lookup a large range of cells, we can check to see if it needs all of them, or if it just cares about the first one. So for `ISNA` we could look at `FormulaArgs.ISNA[0]` to get `Value` so we know that it needs only a single argument that is not an array, so if we call it with `ISNA(A1:A99999)`, it would really only lookup `A1`. This might be premature optimization however.
7
8 * CELL - Requires changes to Parser/Sheet so that the raw cell is returned to the function. The raw cell should contain all information necessary for returning specified info.
9-* ADDRESS - In order to implement this, cells need to be aware of their sheet.
10 * COLUMNS
11 * HLOOKUP
12 * INDEX
13diff --git a/dist/Formulas/AllFormulas.js b/dist/Formulas/AllFormulas.js
14index 750ec6a..e6d28ab 100644
15--- a/dist/Formulas/AllFormulas.js
16+++ b/dist/Formulas/AllFormulas.js
17@@ -101,6 +101,7 @@ exports.ROW = Info_1.ROW;
18 exports.ISFORMULA = Info_1.ISFORMULA;
19 var Lookup_1 = require("./Lookup");
20 exports.CHOOSE = Lookup_1.CHOOSE;
21+exports.ADDRESS = Lookup_1.ADDRESS;
22 var Convert_1 = require("./Convert");
23 exports.TO_DATE = Convert_1.TO_DATE;
24 exports.TO_DOLLARS = Convert_1.TO_DOLLARS;
25diff --git a/dist/Formulas/Lookup.js b/dist/Formulas/Lookup.js
26index 8d21a57..a746362 100644
27--- a/dist/Formulas/Lookup.js
28+++ b/dist/Formulas/Lookup.js
29@@ -25,3 +25,92 @@ var CHOOSE = function (index) {
30 return data[i - 1];
31 };
32 exports.CHOOSE = CHOOSE;
33+var ADDRESS = function (row, column, absoluteVsRelativeMode, useA1Notation, sheet) {
34+ if (absoluteVsRelativeMode === void 0) { absoluteVsRelativeMode = 1; }
35+ if (useA1Notation === void 0) { useA1Notation = true; }
36+ ArgsChecker_1.ArgsChecker.checkLengthWithin(arguments, 2, 5, "ADDRESS");
37+ row = TypeConverter_1.TypeConverter.firstValueAsNumber(row);
38+ column = TypeConverter_1.TypeConverter.firstValueAsNumber(column);
39+ absoluteVsRelativeMode = TypeConverter_1.TypeConverter.firstValueAsNumber(absoluteVsRelativeMode);
40+ useA1Notation = TypeConverter_1.TypeConverter.firstValueAsBoolean(useA1Notation);
41+ sheet = (sheet === undefined) ? sheet : TypeConverter_1.TypeConverter.firstValueAsString(sheet);
42+ function calculateColumnLetters(n) {
43+ n--; // ensuring 1-indexed.
44+ var ordA = 'a'.charCodeAt(0);
45+ var ordZ = 'z'.charCodeAt(0);
46+ var len = ordZ - ordA + 1;
47+ var s = "";
48+ while (n >= 0) {
49+ s = String.fromCharCode(n % len + ordA) + s;
50+ n = Math.floor(n / len) - 1;
51+ }
52+ return s.toUpperCase();
53+ }
54+ if (row < 1) {
55+ throw new Errors_1.ValueError("Function ADDRESS parameter 1 value is " + row
56+ + ", but it should be greater than or equal to 1.");
57+ }
58+ if (column < 1) {
59+ throw new Errors_1.ValueError("Function ADDRESS parameter 2 value is " + column
60+ + ", but it should be greater than or equal to 1.");
61+ }
62+ if (absoluteVsRelativeMode > 4 || absoluteVsRelativeMode < 1) {
63+ throw new Errors_1.NumError("Function ADDRESS parameter 3 value is " + absoluteVsRelativeMode
64+ + ", while valid values are between 1 and 4 inclusively");
65+ }
66+ var cellNotation = "";
67+ if (useA1Notation) {
68+ var columnLetter = calculateColumnLetters(column);
69+ switch (absoluteVsRelativeMode) {
70+ // 1 is row and column absolute (e.g. $A$1)
71+ case 1:
72+ cellNotation = cellNotation + "$" + columnLetter + "$" + row.toString();
73+ break;
74+ // 2 is row absolute and column relative (e.g. A$1)
75+ case 2:
76+ cellNotation = cellNotation + columnLetter + "$" + row.toString();
77+ break;
78+ // 3 is row relative and column absolute (e.g. $A1)
79+ case 3:
80+ cellNotation = cellNotation + "$" + columnLetter + row.toString();
81+ break;
82+ // 4 is row and column relative (e.g. A1).
83+ case 4:
84+ cellNotation = cellNotation + columnLetter + row.toString();
85+ break;
86+ }
87+ }
88+ else {
89+ switch (absoluteVsRelativeMode) {
90+ // 1 is row and column absolute (e.g. R1C1)
91+ case 1:
92+ cellNotation = "R" + row.toString() + "C" + column.toString();
93+ break;
94+ // 2 is row absolute and column relative (e.g. R1C[1])
95+ case 2:
96+ cellNotation = "R" + row.toString() + "C[" + column.toString() + "]";
97+ break;
98+ // 3 is row relative and column absolute (e.g. R[1]C1)
99+ case 3:
100+ cellNotation = "R[" + row.toString() + "]C" + column.toString();
101+ break;
102+ // 4 is row and column relative (e.g. R[1]C[1]).
103+ case 4:
104+ cellNotation = "R[" + row.toString() + "]C[" + column.toString() + "]";
105+ break;
106+ }
107+ }
108+ if (sheet !== undefined) {
109+ // If the sheet name contains non-alpha numeric characters, wrap it in single-quotes.
110+ // Safe sheet name examples: 'sheet_one', 'sheetone'.
111+ // Unsafe sheet name examples: '_one', '12345sheet', 'sheet 1'.
112+ if (sheet.match(/^[a-zA-Z]+[a-zA-Z0-9_]*$/) === null) {
113+ return "'" + sheet + "'!" + cellNotation;
114+ }
115+ return sheet + "!" + cellNotation;
116+ }
117+ else {
118+ return cellNotation;
119+ }
120+};
121+exports.ADDRESS = ADDRESS;
122diff --git a/src/Formulas/AllFormulas.ts b/src/Formulas/AllFormulas.ts
123index fa91fa8..55cc548 100644
124--- a/src/Formulas/AllFormulas.ts
125+++ b/src/Formulas/AllFormulas.ts
126@@ -101,7 +101,8 @@ import {
127 ISFORMULA
128 } from "./Info";
129 import {
130- CHOOSE
131+ CHOOSE,
132+ ADDRESS
133 } from "./Lookup";
134 import {
135 TO_DATE,
136@@ -505,5 +506,6 @@ export {
137 TO_DOLLARS,
138 TO_PERCENT,
139 TO_TEXT,
140- ISFORMULA
141+ ISFORMULA,
142+ ADDRESS
143 }
144\ No newline at end of file
145diff --git a/src/Formulas/Lookup.ts b/src/Formulas/Lookup.ts
146index 88cf7c4..9d829f5 100644
147--- a/src/Formulas/Lookup.ts
148+++ b/src/Formulas/Lookup.ts
149@@ -2,7 +2,7 @@ import {
150 ArgsChecker
151 } from "../Utilities/ArgsChecker";
152 import {
153- NumError
154+ NumError, ValueError
155 } from "../Errors";
156 import {
157 TypeConverter
158@@ -30,6 +30,97 @@ let CHOOSE = function (index, ...values) {
159 };
160
161
162+let ADDRESS = function (row, column, absoluteVsRelativeMode = 1, useA1Notation = true, sheet?) {
163+ ArgsChecker.checkLengthWithin(arguments, 2, 5, "ADDRESS");
164+ row = TypeConverter.firstValueAsNumber(row);
165+ column = TypeConverter.firstValueAsNumber(column);
166+ absoluteVsRelativeMode = TypeConverter.firstValueAsNumber(absoluteVsRelativeMode);
167+ useA1Notation = TypeConverter.firstValueAsBoolean(useA1Notation);
168+ sheet = (sheet === undefined) ? sheet : TypeConverter.firstValueAsString(sheet);
169+
170+ function calculateColumnLetters(n) {
171+ n--; // ensuring 1-indexed.
172+ let ordA = 'a'.charCodeAt(0);
173+ let ordZ = 'z'.charCodeAt(0);
174+ let len = ordZ - ordA + 1;
175+
176+ let s = "";
177+ while(n >= 0) {
178+ s = String.fromCharCode(n % len + ordA) + s;
179+ n = Math.floor(n / len) - 1;
180+ }
181+ return s.toUpperCase();
182+ }
183+
184+ if (row < 1) {
185+ throw new ValueError("Function ADDRESS parameter 1 value is " + row
186+ + ", but it should be greater than or equal to 1.");
187+ }
188+ if (column < 1) {
189+ throw new ValueError("Function ADDRESS parameter 2 value is " + column
190+ + ", but it should be greater than or equal to 1.");
191+ }
192+ if (absoluteVsRelativeMode > 4 || absoluteVsRelativeMode < 1) {
193+ throw new NumError("Function ADDRESS parameter 3 value is " + absoluteVsRelativeMode
194+ + ", while valid values are between 1 and 4 inclusively");
195+ }
196+
197+ let cellNotation = "";
198+ if (useA1Notation) {
199+ let columnLetter = calculateColumnLetters(column);
200+ switch (absoluteVsRelativeMode) {
201+ // 1 is row and column absolute (e.g. $A$1)
202+ case 1:
203+ cellNotation = cellNotation + "$" + columnLetter + "$" + row.toString();
204+ break;
205+ // 2 is row absolute and column relative (e.g. A$1)
206+ case 2:
207+ cellNotation = cellNotation + columnLetter + "$" + row.toString();
208+ break;
209+ // 3 is row relative and column absolute (e.g. $A1)
210+ case 3:
211+ cellNotation = cellNotation + "$" + columnLetter + row.toString();
212+ break;
213+ // 4 is row and column relative (e.g. A1).
214+ case 4:
215+ cellNotation = cellNotation + columnLetter + row.toString();
216+ break;
217+ }
218+ } else {
219+ switch (absoluteVsRelativeMode) {
220+ // 1 is row and column absolute (e.g. R1C1)
221+ case 1:
222+ cellNotation = "R" + row.toString() + "C" + column.toString();
223+ break;
224+ // 2 is row absolute and column relative (e.g. R1C[1])
225+ case 2:
226+ cellNotation = "R" + row.toString() + "C[" + column.toString() + "]";
227+ break;
228+ // 3 is row relative and column absolute (e.g. R[1]C1)
229+ case 3:
230+ cellNotation = "R[" + row.toString() + "]C" + column.toString();
231+ break;
232+ // 4 is row and column relative (e.g. R[1]C[1]).
233+ case 4:
234+ cellNotation = "R[" + row.toString() + "]C[" + column.toString() + "]";
235+ break;
236+ }
237+ }
238+ if (sheet !== undefined) {
239+ // If the sheet name contains non-alpha numeric characters, wrap it in single-quotes.
240+ // Safe sheet name examples: 'sheet_one', 'sheetone'.
241+ // Unsafe sheet name examples: '_one', '12345sheet', 'sheet 1'.
242+ if (sheet.match(/^[a-zA-Z]+[a-zA-Z0-9_]*$/) === null) {
243+ return "'" + sheet + "'!" + cellNotation;
244+ }
245+ return sheet + "!" + cellNotation;
246+
247+ } else {
248+ return cellNotation;
249+ }
250+};
251+
252 export {
253- CHOOSE
254+ CHOOSE,
255+ ADDRESS
256 }
257\ No newline at end of file
258diff --git a/tests/Formulas/LookupTest.ts b/tests/Formulas/LookupTest.ts
259index d72cad6..672d344 100644
260--- a/tests/Formulas/LookupTest.ts
261+++ b/tests/Formulas/LookupTest.ts
262@@ -1,5 +1,6 @@
263 import {
264- CHOOSE
265+ CHOOSE,
266+ ADDRESS
267 } from "../../src/Formulas/Lookup";
268 import * as ERRORS from "../../src/Errors";
269 import {
270@@ -25,3 +26,40 @@ test("CHOOSE", function(){
271 CHOOSE.apply(this, [0, 1, 2, 3]);
272 }, ERRORS.NUM_ERROR);
273 });
274+
275+
276+test("ADDRESS", function(){
277+ assertEquals(ADDRESS(2170, 2, 4, true, "SheetOne"), "SheetOne!B2170");
278+ assertEquals(ADDRESS(2170, 2, 4, true, "Sheet_One"), "Sheet_One!B2170");
279+ assertEquals(ADDRESS(2170, 2, 4, true, "Sheet!One"), "'Sheet!One'!B2170");
280+ assertEquals(ADDRESS(2170, 2, 4, true, "Sheet^One"), "'Sheet^One'!B2170");
281+ assertEquals(ADDRESS(2170, 444, 4, true, "SheetOne"), "SheetOne!QB2170");
282+ assertEquals(ADDRESS(2170, 2, 4, true, "Sheet One"), "'Sheet One'!B2170");
283+ assertEquals(ADDRESS(2170,2,4,true,"Formula Demo Sheet"), "'Formula Demo Sheet'!B2170");
284+ assertEquals(ADDRESS(1, 1, 4, true), "A1");
285+ assertEquals(ADDRESS(2, 1, 4), "A2");
286+ assertEquals(ADDRESS(2, 2, 4), "B2");
287+ assertEquals(ADDRESS(1, 2, 4), "B1");
288+ assertEquals(ADDRESS(1, 1, 4), "A1");
289+ assertEquals(ADDRESS(1, 1, 3), "$A1");
290+ assertEquals(ADDRESS(1, 1, 2), "A$1");
291+ assertEquals(ADDRESS(1, 1, 1), "$A$1");
292+ assertEquals(ADDRESS(1, 1, 4, false), "R[1]C[1]");
293+ assertEquals(ADDRESS(1, 1, 3, false), "R[1]C1");
294+ assertEquals(ADDRESS(1, 1, 2, false), "R1C[1]");
295+ assertEquals(ADDRESS(1, 1, 1, false), "R1C1");
296+ assertEquals(ADDRESS.apply(this, [2170, 2, 1, 100, false]), "FALSE!$B$2170");
297+ assertEquals(ADDRESS.apply(this, [2170, 2, 1, 100, 123456]), "'123456'!$B$2170");
298+ catchAndAssertEquals(function() {
299+ ADDRESS.apply(this, [1]);
300+ }, ERRORS.NA_ERROR);
301+ catchAndAssertEquals(function() {
302+ ADDRESS(1, 2, 5);
303+ }, ERRORS.NUM_ERROR);
304+ catchAndAssertEquals(function() {
305+ ADDRESS(-1, 2, 1);
306+ }, ERRORS.VALUE_ERROR);
307+ catchAndAssertEquals(function() {
308+ ADDRESS(1, -2, 1);
309+ }, ERRORS.VALUE_ERROR);
310+});
311diff --git a/tests/SheetFormulaTest.ts b/tests/SheetFormulaTest.ts
312index 77ddeb8..23c45de 100644
313--- a/tests/SheetFormulaTest.ts
314+++ b/tests/SheetFormulaTest.ts
315@@ -1028,6 +1028,10 @@ test("Sheet ERROR.TYPE", function(){
316 assertFormulaEqualsError('=ERROR.TYPE(10)', NA_ERROR);
317 });
318
319+test("Sheet ADDRESS", function(){
320+ assertFormulaEquals('=ADDRESS(2170, 2, 4, true, "SheetOne")', "SheetOne!B2170");
321+});
322+
323 test("Sheet parsing error", function(){
324 assertFormulaEqualsError('= 10e', PARSE_ERROR);
325 });