commit
message
[Math.SUBTOTAL] formula added and tested
author
Ben Vogt <[email protected]>
date
2017-10-07 16:02:50
stats
9 file(s) changed,
202 insertions(+),
19 deletions(-)
files
DOCS.md
TODO.md
dist/Formulas/AllFormulas.js
dist/Formulas/Math.js
src/Formulas/AllFormulas.ts
src/Formulas/Math.ts
tests/Formulas/MathTest.ts
tests/SheetFormulaTest.ts
tests/Utils/Asserts.ts
1diff --git a/DOCS.md b/DOCS.md
2index a7ae0bb..1449b3d 100644
3--- a/DOCS.md
4+++ b/DOCS.md
5@@ -1601,6 +1601,16 @@
6 @returns {number}
7 @constructor
8 ```
9+
10+### SUBTOTAL
11+
12+```
13+ Calculates subtotals. If a range already contains subtotals, these are not used for further calculations.
14+@param functionCode - A value that stands for another function: 1=AVERAGE, 2=COUNT, 3=COUNTA, 4=MAX, 5=MIN, 6=PRODUCT, 7=STDEV, 8=STDEVP, 9=SUM, 10=VAR, 11=VARP.
15+@param values - The ranges whose cells are included.
16+@returns {Array}
17+@constructor
18+```
19 ## Range
20
21
22diff --git a/TODO.md b/TODO.md
23index d31123a..40c27a9 100644
24--- a/TODO.md
25+++ b/TODO.md
26@@ -38,20 +38,12 @@ Many of these formulas can be written by allowing the Sheet and Parser to return
27 * COUNTBLANK - Requires changes to to Parser/Sheet so when we iterate through a range to return an array, we call a special function that accumulates all values, blank/null/undefined or otherwise.
28
29
30-### Formulas to write
31-* SUBTOTAL
32-* CRITBINOM
33-* F.DIST.RT
34+### Easy formulas to write
35 * HYPGEOMDIST
36-* LOGINV
37-* T.INV
38-* T.INV.2T
39-* TINV
40-* TTEST
41+* CRITBINOM
42 * ZTEST
43 * CLEAN
44 * FIND
45-* FINDB
46 * JOIN
47 * LEFT
48 * LEN
49@@ -63,11 +55,19 @@ Many of these formulas can be written by allowing the Sheet and Parser to return
50 * REPLACE
51 * REPT
52 * RIGHT
53-* ROMAN
54 * SEARCH
55-* SEARCHB
56 * SUBSTITUTE
57 * VALUE
58+
59+### Other formulas to write
60+* F.DIST.RT
61+* LOGINV
62+* T.INV
63+* T.INV.2T
64+* TINV
65+* TTEST
66+* FINDB
67+* SEARCHB
68 * LOGEST
69 * MDETERM
70 * MINVERSE
71diff --git a/dist/Formulas/AllFormulas.js b/dist/Formulas/AllFormulas.js
72index 56af867..4122490 100644
73--- a/dist/Formulas/AllFormulas.js
74+++ b/dist/Formulas/AllFormulas.js
75@@ -76,6 +76,7 @@ exports.FACTDOUBLE = Math_1.FACTDOUBLE;
76 exports.UNARY_PERCENT = Math_1.UNARY_PERCENT;
77 exports.MULTINOMIAL = Math_1.MULTINOMIAL;
78 exports.SERIESSUM = Math_1.SERIESSUM;
79+exports.SUBTOTAL = Math_1.SUBTOTAL;
80 var Range_1 = require("./Range");
81 exports.FREQUENCY = Range_1.FREQUENCY;
82 exports.GROWTH = Range_1.GROWTH;
83diff --git a/dist/Formulas/Math.js b/dist/Formulas/Math.js
84index 4846561..5a348a2 100644
85--- a/dist/Formulas/Math.js
86+++ b/dist/Formulas/Math.js
87@@ -7,6 +7,7 @@ var Serializer_1 = require("../Utilities/Serializer");
88 var CriteriaFunctionFactory_1 = require("../Utilities/CriteriaFunctionFactory");
89 var Errors_1 = require("../Errors");
90 var MathHelpers_1 = require("../Utilities/MathHelpers");
91+var Statistical_1 = require("./Statistical");
92 /**
93 * Returns the greatest common divisor of one or more integers.
94 * @param values - The values or ranges whose factors to consider in a calculation to find the greatest common divisor.
95@@ -1401,3 +1402,48 @@ var SERIESSUM = function (x, n, m, coefficients) {
96 return result;
97 };
98 exports.SERIESSUM = SERIESSUM;
99+/**
100+ * Calculates subtotals. If a range already contains subtotals, these are not used for further calculations.
101+ * @param functionCode - A value that stands for another function: 1=AVERAGE, 2=COUNT, 3=COUNTA, 4=MAX, 5=MIN,
102+ * 6=PRODUCT, 7=STDEV, 8=STDEVP, 9=SUM, 10=VAR, 11=VARP.
103+ * @param values - The ranges whose cells are included.
104+ * @returns {Array}
105+ * @constructor
106+ */
107+var SUBTOTAL = function (functionCode) {
108+ var values = [];
109+ for (var _i = 1; _i < arguments.length; _i++) {
110+ values[_i - 1] = arguments[_i];
111+ }
112+ ArgsChecker_1.ArgsChecker.checkAtLeastLength(arguments, 2, "SUBTOTAL");
113+ functionCode = TypeConverter_1.TypeConverter.firstValueAsNumber(functionCode);
114+ values = Filter_1.Filter.flattenAndThrow(values);
115+ switch (functionCode) {
116+ case 1:
117+ return Statistical_1.AVERAGE(values);
118+ case 2:
119+ return Statistical_1.COUNT(values);
120+ case 3:
121+ return Statistical_1.COUNTA(values);
122+ case 4:
123+ return Statistical_1.MAX(values);
124+ case 5:
125+ return Statistical_1.MIN(values);
126+ case 6:
127+ return PRODUCT.apply(this, values);
128+ case 7:
129+ return Statistical_1.STDEV(values);
130+ case 8:
131+ return Statistical_1.STDEVP(values);
132+ case 9:
133+ return SUM(values);
134+ case 10:
135+ return Statistical_1.VAR(values);
136+ case 11:
137+ return Statistical_1.VARP(values);
138+ default:
139+ throw new Errors_1.ValueError("Value '" + functionCode +
140+ "' does not correspond to a function for use in SUBTOTAL. Value should be between 1 to 11.");
141+ }
142+};
143+exports.SUBTOTAL = SUBTOTAL;
144diff --git a/src/Formulas/AllFormulas.ts b/src/Formulas/AllFormulas.ts
145index 0e7718f..12aff04 100644
146--- a/src/Formulas/AllFormulas.ts
147+++ b/src/Formulas/AllFormulas.ts
148@@ -73,7 +73,8 @@ import {
149 FACTDOUBLE,
150 UNARY_PERCENT,
151 MULTINOMIAL,
152- SERIESSUM
153+ SERIESSUM,
154+ SUBTOTAL
155 } from "./Math";
156 import {
157 FREQUENCY,
158@@ -523,5 +524,6 @@ export {
159 TEXT,
160 FVSCHEDULE,
161 PV,
162- RATE
163+ RATE,
164+ SUBTOTAL
165 }
166\ No newline at end of file
167diff --git a/src/Formulas/Math.ts b/src/Formulas/Math.ts
168index bc535b6..615a76c 100644
169--- a/src/Formulas/Math.ts
170+++ b/src/Formulas/Math.ts
171@@ -23,6 +23,17 @@ import {
172 import {
173 erf, gammaln
174 } from "../Utilities/MathHelpers";
175+import {
176+ AVERAGE,
177+ COUNT,
178+ COUNTA,
179+ MAX,
180+ MIN,
181+ STDEV,
182+ STDEVP,
183+ VAR,
184+ VARP
185+} from "./Statistical";
186
187
188 /**
189@@ -1408,6 +1419,48 @@ let SERIESSUM = function (x, n, m, coefficients) {
190 };
191
192
193+/**
194+ * Calculates subtotals. If a range already contains subtotals, these are not used for further calculations.
195+ * @param functionCode - A value that stands for another function: 1=AVERAGE, 2=COUNT, 3=COUNTA, 4=MAX, 5=MIN,
196+ * 6=PRODUCT, 7=STDEV, 8=STDEVP, 9=SUM, 10=VAR, 11=VARP.
197+ * @param values - The ranges whose cells are included.
198+ * @returns {Array}
199+ * @constructor
200+ */
201+let SUBTOTAL = function (functionCode, ...values: Array<Array<any>>) {
202+ ArgsChecker.checkAtLeastLength(arguments, 2, "SUBTOTAL");
203+ functionCode = TypeConverter.firstValueAsNumber(functionCode);
204+ values = Filter.flattenAndThrow(values);
205+ switch (functionCode) {
206+ case 1:
207+ return AVERAGE(values);
208+ case 2:
209+ return COUNT(values);
210+ case 3:
211+ return COUNTA(values);
212+ case 4:
213+ return MAX(values);
214+ case 5:
215+ return MIN(values);
216+ case 6:
217+ return PRODUCT.apply(this, values);
218+ case 7:
219+ return STDEV(values);
220+ case 8:
221+ return STDEVP(values);
222+ case 9:
223+ return SUM(values);
224+ case 10:
225+ return VAR(values);
226+ case 11:
227+ return VARP(values);
228+ default:
229+ throw new ValueError("Value '" + functionCode +
230+ "' does not correspond to a function for use in SUBTOTAL. Value should be between 1 to 11.");
231+ }
232+};
233+
234+
235 export {
236 ABS,
237 ACOS,
238@@ -1483,5 +1536,6 @@ export {
239 FACTDOUBLE,
240 UNARY_PERCENT,
241 MULTINOMIAL,
242- SERIESSUM
243+ SERIESSUM,
244+ SUBTOTAL
245 }
246\ No newline at end of file
247diff --git a/tests/Formulas/MathTest.ts b/tests/Formulas/MathTest.ts
248index 2102b4b..a76f85b 100644
249--- a/tests/Formulas/MathTest.ts
250+++ b/tests/Formulas/MathTest.ts
251@@ -73,7 +73,8 @@ import {
252 FACTDOUBLE,
253 UNARY_PERCENT,
254 MULTINOMIAL,
255- SERIESSUM
256+ SERIESSUM,
257+ SUBTOTAL
258 } from "../../src/Formulas/Math";
259 import * as ERRORS from "../../src/Errors";
260 import {
261@@ -1529,4 +1530,29 @@ test("SERIESSUM", function(){
262 catchAndAssertEquals(function() {
263 SERIESSUM.apply(this, [1, 0, 1])
264 }, ERRORS.NA_ERROR);
265+});
266+
267+
268+test("SUBTOTAL", function(){
269+ assertEquals(SUBTOTAL(1, [1, 2, 3, 4, 5, 6, 7]), 4);
270+ assertEquals(SUBTOTAL(1, [1, 2, 3, 4, 5, 6, 7], [4, 5, 6, 7, 8, 9, 10]), 5.5);
271+ assertEquals(SUBTOTAL(2, [1, 2, 3, 4, 5, 6, 7], [4, 5, 6, 7, 8, 9, 10]), 14);
272+ assertEquals(SUBTOTAL(3, [1, 2, 3, 4, 5, 6, 7], [4, 5, 6, 7, 8, 9, 10]), 14);
273+ assertEquals(SUBTOTAL(4, [1, 2, 3, 4, 5, 6, 7], [4, 5, 6, 7, 8, 9, 10]), 10);
274+ assertEquals(SUBTOTAL(5, [1, 2, 3, 4, 5, 6, 7], [4, 5, 6, 7, 8, 9, 10]), 1);
275+ assertEquals(SUBTOTAL(6, [1, 2, 3, 4, 5, 6, 7], [4, 5, 6, 7, 8, 9, 10]), 3048192000);
276+ assertEquals(SUBTOTAL(7, [1, 2, 3, 4, 5, 6, 7], [4, 5, 6, 7, 8, 9, 10]), 2.5943726083138543);
277+ assertEquals(SUBTOTAL(8, [1, 2, 3, 4, 5, 6, 7], [4, 5, 6, 7, 8, 9, 10]), 2.5);
278+ assertEquals(SUBTOTAL(9, [1, 2, 3, 4, 5, 6, 7], [4, 5, 6, 7, 8, 9, 10]), 77);
279+ assertEquals(SUBTOTAL(10, [1, 2, 3, 4, 5, 6, 7], [4, 5, 6, 7, 8, 9, 10]), 6.730769230769231);
280+ assertEquals(SUBTOTAL(11, [1, 2, 3, 4, 5, 6, 7], [4, 5, 6, 7, 8, 9, 10]), 6.25);
281+ catchAndAssertEquals(function() {
282+ SUBTOTAL(0, [1, 2, 3, 4, 5, 6, 7]);
283+ }, ERRORS.VALUE_ERROR);
284+ catchAndAssertEquals(function() {
285+ SUBTOTAL(12, [1, 2, 3, 4, 5, 6, 7]);
286+ }, ERRORS.VALUE_ERROR);
287+ catchAndAssertEquals(function() {
288+ SUBTOTAL.apply(this, [1])
289+ }, ERRORS.NA_ERROR);
290 });
291\ No newline at end of file
292diff --git a/tests/SheetFormulaTest.ts b/tests/SheetFormulaTest.ts
293index 5cb1477..601e4f3 100644
294--- a/tests/SheetFormulaTest.ts
295+++ b/tests/SheetFormulaTest.ts
296@@ -1033,6 +1033,10 @@ test("Sheet RATE", function(){
297 assertFormulaEquals('=RATE(12, -100, 400, 100)', 0.2225948800332845);
298 });
299
300+test("Sheet SUBTOTAL", function(){
301+ assertFormulaEquals('=SUBTOTAL([1], [1, 2, 3, 4, 5, 6, 7])', 4);
302+});
303+
304 test("Sheet parsing error", function(){
305 assertFormulaEqualsError('= 10e', PARSE_ERROR);
306 assertFormulaEqualsError('= SUM(', PARSE_ERROR);
307diff --git a/tests/Utils/Asserts.ts b/tests/Utils/Asserts.ts
308index e49fdd7..d113ba4 100644
309--- a/tests/Utils/Asserts.ts
310+++ b/tests/Utils/Asserts.ts
311@@ -82,12 +82,22 @@ function catchAndAssertEquals(toExecute : Function, expected) {
312 }
313 }
314
315+/**
316+ * Print description of test, and run test.
317+ * @param {string} description - To print.
318+ * @param {Function} toRun - Test function to run.
319+ */
320 function test(description: string, toRun: Function) {
321 console.log("Test:", description);
322 toRun();
323 }
324
325
326+/**
327+ * Assert formula will result in a particular error.
328+ * @param {string} formula
329+ * @param {string} errorString
330+ */
331 function assertFormulaEqualsError(formula: string, errorString: string) {
332 let sheet = new Sheet();
333 sheet.setCell("A1", formula);
334@@ -96,6 +106,11 @@ function assertFormulaEqualsError(formula: string, errorString: string) {
335 assertEquals(cell.getValue(), null);
336 }
337
338+/**
339+ * Assert formula will result in a particular value.
340+ * @param {string} formula
341+ * @param expectation
342+ */
343 function assertFormulaEquals(formula: string, expectation: any) {
344 let sheet = new Sheet();
345 sheet.setCell("A1", formula);
346@@ -104,6 +119,13 @@ function assertFormulaEquals(formula: string, expectation: any) {
347 assertEquals(cell.getValue(), expectation);
348 }
349
350+/**
351+ * Assert formula will equal a result, depends on a specific cell reference.
352+ * @param {string} refId - Cell ID, eg: A1
353+ * @param value - Value for refId.
354+ * @param {string} formula - Formula to evaluate.
355+ * @param expectation - Expected result.
356+ */
357 function assertFormulaEqualsDependsOnReference(refId: string, value: any, formula: string, expectation: any) {
358 let sheet = new Sheet();
359 sheet.setCell(refId, value);
360@@ -113,6 +135,11 @@ function assertFormulaEqualsDependsOnReference(refId: string, value: any, formul
361 assertEquals(cell.getValue(), expectation);
362 }
363
364+/**
365+ * Assert that the evaluation of a formula results in a specific type.
366+ * @param {string} formula
367+ * @param {string} type
368+ */
369 function assertFormulaResultsInType(formula: string, type: string) {
370 let sheet = new Sheet();
371 sheet.setCell("A1", formula);
372@@ -121,6 +148,11 @@ function assertFormulaResultsInType(formula: string, type: string) {
373 assertEquals(typeof cell.getValue(), type);
374 }
375
376+/**
377+ * Assert formula will result in a particular array.
378+ * @param {string} formula
379+ * @param expectation
380+ */
381 function assertFormulaEqualsArray(formula: string, expectation: any) {
382 let sheet = new Sheet();
383 sheet.setCell("A1", formula);
384@@ -132,7 +164,15 @@ function assertFormulaEqualsArray(formula: string, expectation: any) {
385 }
386 }
387
388-// WARNING: Locking in Date by overriding prototypes.
389+/**
390+ * Lock in Date by overriding prototypes. WARNING: Should be used sparingly and cautiously.
391+ * @param year
392+ * @param month
393+ * @param day
394+ * @param hour
395+ * @param minute
396+ * @param second
397+ */
398 function lockDate(year, month, day, hour, minute, second) {
399 let d = new Date(year, month, day, hour, minute, second);
400 Date.prototype.constructor = function () {