commit
message
[COLUMNS] formula added and tested
author
Ben Vogt <[email protected]>
date
2017-09-09 15:59:23
stats
8 file(s) changed,
185 insertions(+),
8 deletions(-)
files
DOCS.md
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/DOCS.md b/DOCS.md
2index 4ef6754..ffb14e2 100644
3--- a/DOCS.md
4+++ b/DOCS.md
5@@ -836,6 +836,28 @@
6 @param values - Array of potential value to return. Required. May be a reference to a cell or an individual value.
7 @constructor
8 ```
9+
10+### ADDRESS
11+
12+```
13+ Returns a text representation of a cell address based on the row, column, and sheet.
14+@param row - Row of cell address.
15+@param column - Column of cell address
16+@param {number} absoluteVsRelativeMode - [OPTIONAL - default is 1] Should return a relative(A1, vs $A$1) or absolute address. 1 is row and column absolute (e.g. $A$1), 2 is row absolute and column relative (e.g. A$1), 3 is row relative and column absolute (e.g. $A1), 4 is row and column relative (e.g. A1).
17+@param {boolean} useA1Notation - [OPTIONAL - default is TRUE] Should use A1 notation.
18+@param sheet - [OPTIONAL] Sheet name to use in address.
19+@returns {string}
20+@constructor
21+```
22+
23+### COLUMNS
24+
25+```
26+ Gets the number of columns in a specified array or range.
27+@param value - The array of range to consider.
28+@returns {number}
29+@constructor
30+```
31 ## Math
32
33
34diff --git a/TODO.md b/TODO.md
35index f2d42bb..5f6f938 100644
36--- a/TODO.md
37+++ b/TODO.md
38@@ -23,7 +23,6 @@ For example `=#N/A` should force an error to be thrown inside the cell.
39 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.
40
41 * 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.
42-* COLUMNS
43 * HLOOKUP
44 * INDEX
45 * INDIRECT
46diff --git a/dist/Formulas/AllFormulas.js b/dist/Formulas/AllFormulas.js
47index e6d28ab..db5ef61 100644
48--- a/dist/Formulas/AllFormulas.js
49+++ b/dist/Formulas/AllFormulas.js
50@@ -102,6 +102,7 @@ exports.ISFORMULA = Info_1.ISFORMULA;
51 var Lookup_1 = require("./Lookup");
52 exports.CHOOSE = Lookup_1.CHOOSE;
53 exports.ADDRESS = Lookup_1.ADDRESS;
54+exports.COLUMNS = Lookup_1.COLUMNS;
55 var Convert_1 = require("./Convert");
56 exports.TO_DATE = Convert_1.TO_DATE;
57 exports.TO_DOLLARS = Convert_1.TO_DOLLARS;
58diff --git a/dist/Formulas/Lookup.js b/dist/Formulas/Lookup.js
59index a746362..713ef5e 100644
60--- a/dist/Formulas/Lookup.js
61+++ b/dist/Formulas/Lookup.js
62@@ -4,6 +4,7 @@ var ArgsChecker_1 = require("../Utilities/ArgsChecker");
63 var Errors_1 = require("../Errors");
64 var TypeConverter_1 = require("../Utilities/TypeConverter");
65 var Filter_1 = require("../Utilities/Filter");
66+var Cell_1 = require("../Cell");
67 /**
68 * Returns an element from a list of choices based on index.
69 * @param index - Which choice to return. Index starts at 1.
70@@ -25,6 +26,18 @@ var CHOOSE = function (index) {
71 return data[i - 1];
72 };
73 exports.CHOOSE = CHOOSE;
74+/**
75+ * Returns a text representation of a cell address based on the row, column, and sheet.
76+ * @param row - Row of cell address.
77+ * @param column - Column of cell address
78+ * @param {number} absoluteVsRelativeMode - [OPTIONAL - default is 1] Should return a relative(A1, vs $A$1) or absolute address. 1 is row and
79+ * column absolute (e.g. $A$1), 2 is row absolute and column relative (e.g. A$1), 3 is row relative and column absolute
80+ * (e.g. $A1), 4 is row and column relative (e.g. A1).
81+ * @param {boolean} useA1Notation - [OPTIONAL - default is TRUE] Should use A1 notation.
82+ * @param sheet - [OPTIONAL] Sheet name to use in address.
83+ * @returns {string}
84+ * @constructor
85+ */
86 var ADDRESS = function (row, column, absoluteVsRelativeMode, useA1Notation, sheet) {
87 if (absoluteVsRelativeMode === void 0) { absoluteVsRelativeMode = 1; }
88 if (useA1Notation === void 0) { useA1Notation = true; }
89@@ -114,3 +127,33 @@ var ADDRESS = function (row, column, absoluteVsRelativeMode, useA1Notation, shee
90 }
91 };
92 exports.ADDRESS = ADDRESS;
93+/**
94+ * Gets the number of columns in a specified array or range.
95+ * @param value - The array of range to consider.
96+ * @returns {number}
97+ * @constructor
98+ */
99+var COLUMNS = function (value) {
100+ ArgsChecker_1.ArgsChecker.checkLength(arguments, 1, "COLUMNS");
101+ if (value instanceof Array) {
102+ if (value.length === 0) {
103+ throw new Errors_1.RefError("Reference does not exist.");
104+ }
105+ else if (value.length === 1) {
106+ return 1;
107+ }
108+ if (value[0] instanceof Cell_1.Cell) {
109+ var start = value[0];
110+ var end = value[value.length - 1];
111+ return end.getColumn() - start.getColumn() + 1; // counting columns inclusively
112+ }
113+ else {
114+ // if the array passed in is just values, assume that each value is a column.
115+ return value.length;
116+ }
117+ }
118+ else {
119+ return 1;
120+ }
121+};
122+exports.COLUMNS = COLUMNS;
123diff --git a/src/Formulas/AllFormulas.ts b/src/Formulas/AllFormulas.ts
124index 55cc548..fe28789 100644
125--- a/src/Formulas/AllFormulas.ts
126+++ b/src/Formulas/AllFormulas.ts
127@@ -102,7 +102,8 @@ import {
128 } from "./Info";
129 import {
130 CHOOSE,
131- ADDRESS
132+ ADDRESS,
133+ COLUMNS
134 } from "./Lookup";
135 import {
136 TO_DATE,
137@@ -507,5 +508,6 @@ export {
138 TO_PERCENT,
139 TO_TEXT,
140 ISFORMULA,
141- ADDRESS
142+ ADDRESS,
143+ COLUMNS
144 }
145\ No newline at end of file
146diff --git a/src/Formulas/Lookup.ts b/src/Formulas/Lookup.ts
147index 9d829f5..6c188b7 100644
148--- a/src/Formulas/Lookup.ts
149+++ b/src/Formulas/Lookup.ts
150@@ -2,7 +2,7 @@ import {
151 ArgsChecker
152 } from "../Utilities/ArgsChecker";
153 import {
154- NumError, ValueError
155+ NumError, RefError, ValueError
156 } from "../Errors";
157 import {
158 TypeConverter
159@@ -10,6 +10,7 @@ import {
160 import {
161 Filter
162 } from "../Utilities/Filter";
163+import {Cell} from "../Cell";
164
165
166 /**
167@@ -29,7 +30,18 @@ let CHOOSE = function (index, ...values) {
168 return data[i-1];
169 };
170
171-
172+/**
173+ * Returns a text representation of a cell address based on the row, column, and sheet.
174+ * @param row - Row of cell address.
175+ * @param column - Column of cell address
176+ * @param {number} absoluteVsRelativeMode - [OPTIONAL - default is 1] Should return a relative(A1, vs $A$1) or absolute address. 1 is row and
177+ * column absolute (e.g. $A$1), 2 is row absolute and column relative (e.g. A$1), 3 is row relative and column absolute
178+ * (e.g. $A1), 4 is row and column relative (e.g. A1).
179+ * @param {boolean} useA1Notation - [OPTIONAL - default is TRUE] Should use A1 notation.
180+ * @param sheet - [OPTIONAL] Sheet name to use in address.
181+ * @returns {string}
182+ * @constructor
183+ */
184 let ADDRESS = function (row, column, absoluteVsRelativeMode = 1, useA1Notation = true, sheet?) {
185 ArgsChecker.checkLengthWithin(arguments, 2, 5, "ADDRESS");
186 row = TypeConverter.firstValueAsNumber(row);
187@@ -120,7 +132,37 @@ let ADDRESS = function (row, column, absoluteVsRelativeMode = 1, useA1Notation =
188 }
189 };
190
191+
192+/**
193+ * Gets the number of columns in a specified array or range.
194+ * @param value - The array of range to consider.
195+ * @returns {number}
196+ * @constructor
197+ */
198+let COLUMNS = function (value) {
199+ ArgsChecker.checkLength(arguments, 1, "COLUMNS");
200+ if (value instanceof Array) {
201+ if (value.length === 0) {
202+ throw new RefError("Reference does not exist.");
203+ } else if (value.length === 1) {
204+ return 1;
205+ }
206+ if (value[0] instanceof Cell) {
207+ let start = value[0];
208+ let end = value[value.length - 1];
209+ return end.getColumn() - start.getColumn() + 1; // counting columns inclusively
210+ } else {
211+ // if the array passed in is just values, assume that each value is a column.
212+ return value.length;
213+ }
214+ } else {
215+ return 1;
216+ }
217+};
218+
219+
220 export {
221 CHOOSE,
222- ADDRESS
223+ ADDRESS,
224+ COLUMNS
225 }
226\ No newline at end of file
227diff --git a/tests/Formulas/LookupTest.ts b/tests/Formulas/LookupTest.ts
228index 672d344..6b31b5f 100644
229--- a/tests/Formulas/LookupTest.ts
230+++ b/tests/Formulas/LookupTest.ts
231@@ -1,6 +1,7 @@
232 import {
233 CHOOSE,
234- ADDRESS
235+ ADDRESS,
236+ COLUMNS
237 } from "../../src/Formulas/Lookup";
238 import * as ERRORS from "../../src/Errors";
239 import {
240@@ -8,6 +9,9 @@ import {
241 test,
242 assertEquals
243 } from "../Utils/Asserts";
244+import {
245+ Cell
246+} from "../../src/Cell";
247
248
249 test("CHOOSE", function(){
250@@ -63,3 +67,57 @@ test("ADDRESS", function(){
251 ADDRESS(1, -2, 1);
252 }, ERRORS.VALUE_ERROR);
253 });
254+
255+
256+test("COLUMNS", function(){
257+ assertEquals(COLUMNS(1), 1);
258+ assertEquals(COLUMNS("str"), 1);
259+ assertEquals(COLUMNS(false), 1);
260+ assertEquals(COLUMNS(Cell.BuildFrom("A1", "str")), 1);
261+ assertEquals(COLUMNS([
262+ Cell.BuildFrom("A1", "str"),
263+ Cell.BuildFrom("A2", "str"),
264+ Cell.BuildFrom("A3", "str"),
265+ Cell.BuildFrom("A4", "str"),
266+ Cell.BuildFrom("A5", "str"),
267+ Cell.BuildFrom("A6", "str"),
268+ Cell.BuildFrom("A7", "str"),
269+ Cell.BuildFrom("A8", "str"),
270+ Cell.BuildFrom("B1", "str"),
271+ Cell.BuildFrom("B2", "str"),
272+ Cell.BuildFrom("B3", "str"),
273+ Cell.BuildFrom("B4", "str"),
274+ Cell.BuildFrom("B5", "str"),
275+ Cell.BuildFrom("B6", "str"),
276+ Cell.BuildFrom("B7", "str"),
277+ Cell.BuildFrom("B8", "str"),
278+ Cell.BuildFrom("C1", "str"),
279+ Cell.BuildFrom("C2", "str"),
280+ Cell.BuildFrom("C3", "str"),
281+ Cell.BuildFrom("C4", "str"),
282+ Cell.BuildFrom("C5", "str")
283+ ]), 3);
284+ assertEquals(COLUMNS([
285+ Cell.BuildFrom("A1", "str"),
286+ Cell.BuildFrom("A2", "str"),
287+ Cell.BuildFrom("A3", "str"),
288+ Cell.BuildFrom("A4", "str"),
289+ Cell.BuildFrom("A5", "str"),
290+ Cell.BuildFrom("A6", "str"),
291+ Cell.BuildFrom("A7", "str"),
292+ Cell.BuildFrom("A8", "str"),
293+ Cell.BuildFrom("B1", "str")
294+ ]), 2);
295+ assertEquals(COLUMNS([
296+ Cell.BuildFrom("A1", "str"),
297+ Cell.BuildFrom("A2", "str"),
298+ Cell.BuildFrom("A3", "str")
299+ ]), 1);
300+ assertEquals(COLUMNS([1, 2, 3, 4]), 4);
301+ catchAndAssertEquals(function() {
302+ COLUMNS.apply(this, []);
303+ }, ERRORS.NA_ERROR);
304+ catchAndAssertEquals(function() {
305+ COLUMNS([]);
306+ }, ERRORS.REF_ERROR);
307+});
308diff --git a/tests/SheetFormulaTest.ts b/tests/SheetFormulaTest.ts
309index 23c45de..5ab35da 100644
310--- a/tests/SheetFormulaTest.ts
311+++ b/tests/SheetFormulaTest.ts
312@@ -1032,8 +1032,16 @@ test("Sheet ADDRESS", function(){
313 assertFormulaEquals('=ADDRESS(2170, 2, 4, true, "SheetOne")', "SheetOne!B2170");
314 });
315
316+test("Sheet COLUMNS", function(){
317+ assertFormulaEquals('=COLUMNS(1)', 1);
318+ assertFormulaEquals('=COLUMNS([1, 2, 3, 4])', 4);
319+ assertFormulaEquals('=COLUMNS(M1)', 1);
320+ assertFormulaEquals('=COLUMNS(B1:M44)', 12);
321+});
322+
323 test("Sheet parsing error", function(){
324 assertFormulaEqualsError('= 10e', PARSE_ERROR);
325+ assertFormulaEqualsError('= SUM(', PARSE_ERROR);
326 });
327
328 test("Sheet *", function(){