commit
message
Added Formula.AVERAGEIF (with TODOs) and updated TODOs in README.md
author
Ben Vogt <[email protected]>
date
2017-02-15 05:08:42
stats
3 file(s) changed,
71 insertions(+),
2 deletions(-)
files
README.md
src/RawFormulas/RawFormulas.ts
tests/FormulasTest.ts
1diff --git a/README.md b/README.md
2index b6c62ad..929b694 100644
3--- a/README.md
4+++ b/README.md
5@@ -26,4 +26,6 @@ The resulting errors from these bugs aren't that bad. I'll mark them down, and i
6 How do we protect against users injecting data that looks like `console.log(sensitive_data)` when we evaluate variables
7 inside parser.js? If we ever want to impliment custom formulas, or even accept data in raw format, we need to guard
8 against this. Or else someone could load a CSV with javascript and when our spreadsheet opens it, then suddenly
9-arbitrary javascript is executed in the client machine.
10\ No newline at end of file
11+arbitrary javascript is executed in the client machine.
12+
13+### Criteria evaluations should accept "<>"
14\ No newline at end of file
15diff --git a/src/RawFormulas/RawFormulas.ts b/src/RawFormulas/RawFormulas.ts
16index ab64252..12d9734 100644
17--- a/src/RawFormulas/RawFormulas.ts
18+++ b/src/RawFormulas/RawFormulas.ts
19@@ -70,7 +70,6 @@ import { CellError } from "../Errors"
20 import * as ERRORS from "../Errors"
21
22 var ACCRINT = Formula["ACCRINT"];
23-var AVERAGEIF = Formula["AVERAGEIF"];
24 var BIN2DEC = Formula["BIN2DEC"];
25 var BIN2HEX = Formula["BIN2HEX"];
26 var BIN2OCT = Formula["BIN2OCT"];
27@@ -129,6 +128,37 @@ var SUMX2PY2 = Formula["SUMX2PY2"];
28 var TRUNC = Formula["TRUNC"];
29 var YEARFRAC = Formula["YEARFRAC"];
30
31+/**
32+ * Returns the average of a range depending on criteria.
33+ * @param values[0] criteria_range - The range to check against criterion.
34+ * @param values[1] criterion - The pattern or test to apply to criteria_range.
35+ * @param values[2] average_range - [optional] The range to average. If not included, criteria_range is used for the
36+ * average instead.
37+ * @returns {number}
38+ * @constructor
39+ * TODO: This needs to take nested range values.
40+ * TODO: This needs to also accept a third parameter "average_range"
41+ */
42+var AVERAGEIF = function (...values) {
43+ checkArgumentsLength(values, 2);
44+ var range = values[0];
45+ var criteriaEvaluation = CriteriaFunctionFactory.createCriteriaFunction(values[1]);
46+
47+ var result = 0;
48+ var count = 0;
49+ for (var i = 0; i < range.length; i++) {
50+ var val = valueToNumber(range[i]);
51+ if (criteriaEvaluation(val)) {
52+ result = result + val;
53+ count++;
54+ }
55+ }
56+ if (count === 0) {
57+ throw new CellError(ERRORS.DIV_ZERO_ERROR, "Evaluation of function AVERAGEIF caused a divide by zero error.");
58+ }
59+ return result / count;
60+};
61+
62 /**
63 * Rounds a number up to the nearest integer multiple of specified significance.
64 * @param values[0] The value to round up to the nearest integer multiple of factor.
65@@ -230,6 +260,7 @@ var COUNT = function (...values) : number {
66 * front of them. If it is neither, it will compared with values in the range using equality comparison.
67 * @returns {number}
68 * @constructor
69+ * TODO: This needs to take nested range values.
70 */
71 var COUNTIF = function (...values) {
72 checkArgumentsLength(values, 2);
73@@ -248,6 +279,15 @@ var COUNTIF = function (...values) {
74 return count;
75 };
76
77+/**
78+ * Returns the count of a range depending on multiple criteria.
79+ * @param values[0] criteria_range1 - The range to check against criterion1.
80+ * @param values[1] criterion1 - The pattern or test to apply to criteria_range1.
81+ * @param values[2...N] Repeated sets of ranges and criterion to check.
82+ * @returns {number} count
83+ * @constructor
84+ * TODO: This needs to take nested range values.
85+ */
86 var COUNTIFS = function (...values) {
87 checkArgumentsAtLeastLength(values, 2);
88 var criteriaEvaluationFunctions = values.map(function (criteria, index) {
89@@ -380,6 +420,7 @@ var ROUNDUP = function (...values) {
90 * @param values[2] (optional) The range to be summed, if different from range.
91 * @returns {number}
92 * @constructor
93+ * TODO: This needs to take nested range values.
94 */
95 var SUMIF = function (...values) {
96 checkArgumentsAtWithin(values, 2, 3);
97diff --git a/tests/FormulasTest.ts b/tests/FormulasTest.ts
98index aec77ae..c746642 100644
99--- a/tests/FormulasTest.ts
100+++ b/tests/FormulasTest.ts
101@@ -258,7 +258,33 @@ catchAndAssertEquals(function() {
102 }, ERRORS.REF_ERROR);
103
104
105+// Test AVERAGEIF
106 assertEquals(AVERAGEIF([1, 5, 10], '>2'), 7.5);
107+assertEquals(AVERAGEIF([1, 5, 10], ">4"), 7.5);
108+assertEquals(AVERAGEIF([1, 2, 2, 2, 2, 2, 2, 2], ">1"), 2);
109+assertEquals(AVERAGEIF([1, 5, 10], 5), 5);
110+assertEquals(AVERAGEIF([1, 5, 5, 5, 10, 5], 5), 5);
111+assertEquals(AVERAGEIF([1, 5, 5, 5, 10, 5], 10), 10);
112+assertEquals(AVERAGEIF([1, 5, 5, 5, 10, 5], ">5"), 10);
113+assertEquals(AVERAGEIF([1, 5, 5, 5, 10, 5], "=5"), 5);
114+assertEquals(AVERAGEIF([1, 5, 5, 5, 10, 5], "=10"), 10);
115+assertEquals(AVERAGEIF([1, 5, 5, 5, 10, 5], "= 10 "), 10);
116+assertEquals(AVERAGEIF([1, 5, 5, 5, 10, 5], ">0"), 5.166666666666667);
117+assertEquals(AVERAGEIF([1, 5, 5, 5, 10, 5], ">=5"), 6);
118+assertEquals(AVERAGEIF([1, 5, 5, 5, 10, 5], "<10"), 4.2);
119+assertEquals(AVERAGEIF([1, 5, 5, 5, 10, 5, 44], "<=10"), 5.166666666666667);
120+assertEquals(AVERAGEIF([1, 5, 5, 5, 10, 5], ">4.99"), 6);
121+assertEquals(AVERAGEIF([1, 5, 5, 5, 10, 5], "<4.99"), 1);
122+catchAndAssertEquals(function() {
123+ AVERAGEIF([1, 5, 5, 5, 10, 5], "= 1.0.0 ");
124+}, ERRORS.DIV_ZERO_ERROR);
125+catchAndAssertEquals(function() {
126+ AVERAGEIF([1, 5, 5, 5, 10, 5], "=>5");
127+}, ERRORS.DIV_ZERO_ERROR);
128+catchAndAssertEquals(function() {
129+ AVERAGEIF([1, 5, 5, 5, 10, 5], "==5");
130+}, ERRORS.DIV_ZERO_ERROR);
131+
132
133 assertEquals(BIN2DEC(1010101010), -342);
134