commit
message
Added Formula.SUMIF
author
Ben Vogt <[email protected]>
date
2017-02-10 02:11:41
stats
4 file(s) changed,
125 insertions(+),
3 deletions(-)
files
src/RawFormulas/RawFormulas.ts
tests/FormulasTest.ts
tests/SheetFormulaTest.ts
tests/SheetTest.ts
1diff --git a/src/RawFormulas/RawFormulas.ts b/src/RawFormulas/RawFormulas.ts
2index 37ea38e..d506dae 100644
3--- a/src/RawFormulas/RawFormulas.ts
4+++ b/src/RawFormulas/RawFormulas.ts
5@@ -255,9 +255,88 @@ var ROUNDUP = function (...values) {
6 return Math.ceil(n * Math.pow(10, d)) / Math.pow(10, d);
7 };
8
9+/**
10+ * Returns a conditional sum across a range.
11+ * @param values[0] The range which is tested against criterion.
12+ * @param values[1] The pattern or test to apply to range. If the range to check against contains text, this must be a
13+ * string. It can be a comparison based string (e.g. "=1", "<1", ">=1") or it can be a wild-card string, in which *
14+ * matches any number of characters, and ? matches the next character. Both ? and * can be escaped by placing a ~ in
15+ * front of them.
16+ * @param values[2] (optional) The range to be summed, if different from range.
17+ * @returns {number}
18+ * @constructor
19+ */
20+var SUMIF = function (...values) {
21+ checkArgumentsAtWithin(values, 2, 3);
22+ var range = values[0];
23+ var criteria = values[1];
24+ var sumRange = null;
25+ if (values.length === 3) {
26+ sumRange = values[2];
27+ }
28+ // Default criteria does nothing
29+ var criteriaEvaluation = function (x) : boolean {
30+ return false;
31+ };
32+
33+
34+ if (typeof criteria === "number") {
35+ criteriaEvaluation = function (x) : boolean {
36+ return x === criteria;
37+ };
38+ } else if (typeof criteria === "string") {
39+ // https://regex101.com/r/c2hxAZ/6
40+ var comparisonMatches = criteria.match(/(^<=|^>=|^=|^>|^<)\s*(-?[0-9]+([,.][0-9]+)?)\s*$/);
41+ if (comparisonMatches !== null && comparisonMatches.length >= 4 && comparisonMatches[2] !== undefined) {
42+ criteriaEvaluation = function (x) : boolean {
43+ return eval(x + criteria);
44+ };
45+ if (comparisonMatches[1] === "=") {
46+ criteriaEvaluation = function (x) : boolean {
47+ return eval(x + "===" + comparisonMatches[2]);
48+ };
49+ }
50+ } else if (criteria.match(/\*|\~\*|\?|\~\?/) !== null) {
51+ // Regular string
52+ var matches = criteria.match(/\*|\~\*|\?|\~\?/);
53+ if (matches !== null) {
54+ criteriaEvaluation = function (x) : boolean {
55+ try {
56+ // http://stackoverflow.com/questions/26246601/wildcard-string-comparison-in-javascript
57+ return new RegExp("^" + criteria.split("*").join(".*") + "$").test(x);
58+ } catch (e) {
59+ return false;
60+ }
61+ };
62+ } else {
63+ criteriaEvaluation = function (x) : boolean {
64+ return x === criteria;
65+ };
66+ }
67+ } else {
68+ criteriaEvaluation = function (x) : boolean {
69+ return x === criteria;
70+ };
71+ }
72+ }
73+
74+ var sum = 0;
75+ for (var i = 0; i < range.length; i++) {
76+ var x = range[i];
77+ if (sumRange && i > sumRange.length-1) {
78+ continue;
79+ }
80+ if (values.length === 2 && valueCanCoerceToNumber(x) && criteriaEvaluation(x)) {
81+ sum = sum + x;
82+ } else if (values.length === 3 && valueCanCoerceToNumber(sumRange[i]) && criteriaEvaluation(x)) {
83+ sum = sum + sumRange[i];
84+ }
85+ }
86+ return sum;
87+};
88+
89 var SPLIT = Formula["SPLIT"];
90 var SQRTPI = Formula["SQRTPI"];
91-var SUMIF = Formula["SUMIF"];
92 var SUMPRODUCT = Formula["SUMPRODUCT"];
93 var SUMSQ = Formula["SUMSQ"];
94 var SUMX2MY2 = Formula["SUMX2MY2"];
95diff --git a/tests/FormulasTest.ts b/tests/FormulasTest.ts
96index 48d1eb1..8e805dd 100644
97--- a/tests/FormulasTest.ts
98+++ b/tests/FormulasTest.ts
99@@ -1099,7 +1099,45 @@ catchAndAssertEquals(function() {
100 }, ERRORS.NA_ERROR);
101
102
103-assertEquals(SUMIF([1, 5, 10], ">2"), 15);
104+// Test SUMIF
105+assertEquals(SUMIF([1, 5, 10], 5), 5);
106+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], 5), 20);
107+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], 10), 10);
108+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], ">5"), 10);
109+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], "=5"), 20);
110+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], "=1"), 1);
111+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], "= 1 "), 1);
112+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], ">0"), 31);
113+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], ">=5"), 30);
114+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], "<10"), 21);
115+assertEquals(SUMIF([1, 5, 5, 5, 10, 5, 44], "<=10"), 31);
116+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], ">4.99"), 30);
117+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], "<4.99"), 1);
118+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], "= 1.0.0 "), 0);
119+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], "=>5"), 0);
120+assertEquals(SUMIF([1, 5, 5, 5, 10, 5], "==5"), 0);
121+assertEquals(SUMIF(["m", "m", 3, 11, true], "m"), 0);
122+assertEquals(SUMIF(["m", "p", "m"], "m", [1, 1, 1]), 2);
123+assertEquals(SUMIF(["p", "p", "p"], "m", [1, 1, 1]), 0);
124+assertEquals(SUMIF(["p", "p", "p"], "", [1, 1, 1]), 0);
125+assertEquals(SUMIF(["p", "p", "p"], "*", [1, 1, 1]), 3);
126+assertEquals(SUMIF(["mom", "pop", "pap"], "*o*", [1, 1, 1]), 2);
127+assertEquals(SUMIF(["mom", "pop", "pap"], "*a*", [1, 1, 1]), 1);
128+assertEquals(SUMIF(["mom", "pop", "pap"], "p*p", [1, 1, 1]), 2);
129+assertEquals(SUMIF(["mom", "pop", "pap"], "p*p", [1, 1, 1]), 2);
130+assertEquals(SUMIF(["mom", "pop", "pap"], "p*p", [1, 1,]), 1);
131+assertEquals(SUMIF(["pop", "pap"], "p*p", [1, 2, 4]), 3);
132+assertEquals(SUMIF([0, 1, 0, 1], "=1", [1, 2, 4, 8]), 10);
133+catchAndAssertEquals(function() {
134+ SUMIF([0, 1, 0, 1]);
135+}, ERRORS.NA_ERROR);
136+catchAndAssertEquals(function() {
137+ SUMIF();
138+}, ERRORS.NA_ERROR);
139+catchAndAssertEquals(function() {
140+ SUMIF([], "=1", [], true);
141+}, ERRORS.NA_ERROR);
142+
143
144 assertEquals(SUMPRODUCT([1, 5, 10]), 16);
145
146diff --git a/tests/SheetFormulaTest.ts b/tests/SheetFormulaTest.ts
147index 1d30336..30039a0 100644
148--- a/tests/SheetFormulaTest.ts
149+++ b/tests/SheetFormulaTest.ts
150@@ -441,7 +441,7 @@ testFormula('=SQRTPI(9)', 5.317361552716548);
151 testFormula('=SUM(10, 10)', 20);
152
153 // Test SUMIF
154-testFormula('=SUMIF([1, 5, 10], ">2")', 15);
155+testFormula('=SUMIF([1, 5, 10], 5)', 5);
156
157 // Test SUMPRODUCT
158 testFormula('=SUMPRODUCT([1, 5, 10])', 16);
159diff --git a/tests/SheetTest.ts b/tests/SheetTest.ts
160index 1a0d53a..d24a7b1 100644
161--- a/tests/SheetTest.ts
162+++ b/tests/SheetTest.ts
163@@ -39,7 +39,7 @@ var SUM_FORMULA = "=SUM(A1:D1, H1)";
164 var MAX_FORMULA = "=MAX(A2:J2)";
165 var MIN_FORMULA = "=MIN(A3:J3)";
166 var AVERAGE_FORMULA = "=AVERAGE(A4:J4)";
167-var SUM_IF_FORMULA = "=SUMIF(A5:J5,'>5')";
168+var SUM_IF_FORMULA = "=SUMIF(A5:J5,5)";
169 var SUM_REF_FORMULA = "=SUM(K1, K2, K3, K4)";
170 sheet.load([[1, 2, 3, 4, 5, 6, 7, 8, 9, 10, SUM_FORMULA],
171 [-1, -10, 2, 4, 100, 1, 50, 20, 200, -100, MAX_FORMULA],
172@@ -68,7 +68,7 @@ assertEquals(AVERAGE_FORMULA.substr(1), K4.getFormula());
173 assertEquals(null, K4.getError());
174 assertArrayEquals(['A4', 'B4', 'C4', 'D4', 'E4', 'F4', 'G4', 'H4', 'I4', 'J4'], K4.getDependencies());
175 var K5 = sheet.getCell("K5");
176-assertEquals("50", K5.getValue());
177+assertEquals("0", K5.getValue());
178 assertEquals(SUM_IF_FORMULA.substr(1), K5.getFormula());
179 assertEquals(null, K5.getError());
180 assertArrayEquals(['A5', 'B5', 'C5', 'D5', 'E5', 'F5', 'G5', 'H5', 'I5', 'J5'], K5.getDependencies());