spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
Added Formula.COUNTIF and simplified criteria evaluation
author
Ben Vogt <[email protected]>
date
2017-02-13 04:22:34
stats
3 file(s) changed, 241 insertions(+), 133 deletions(-)
files
src/RawFormulas/RawFormulas.ts
src/RawFormulas/Utils.ts
tests/FormulasTest.ts
  1diff --git a/src/RawFormulas/RawFormulas.ts b/src/RawFormulas/RawFormulas.ts
  2index d506dae..2f8a7fa 100644
  3--- a/src/RawFormulas/RawFormulas.ts
  4+++ b/src/RawFormulas/RawFormulas.ts
  5@@ -59,6 +59,7 @@ import {
  6   checkArgumentsAtWithin,
  7   valueCanCoerceToNumber,
  8   filterOutStringValues,
  9+  CriteriaFunctionFactory,
 10   valueToNumber,
 11   checkArgumentsLength,
 12   firstValueAsNumber,
 13@@ -95,6 +96,58 @@ var COMPLEX = Formula["COMPLEX"];
 14 var CONCATENATE = Formula["CONCATENATE"];
 15 var CONVERT = Formula["CONVERT"];
 16 var CORREL = Formula["CORREL"];
 17+var COUNTIFS = Formula["COUNTIFS"];
 18+var COUNTIN = Formula["COUNTIN"];
 19+var COUNTUNIQUE = Formula["COUNTUNIQUE"];
 20+var COVARIANCEP = Formula["COVARIANCEP"];
 21+var COVARIANCES = Formula["COVARIANCES"];
 22+var CSC = Formula["CSC"];
 23+var CSCH = Formula["CSCH"];
 24+var CUMIPMT = Formula["CUMIPMT"];
 25+var CUMPRINC = Formula["CUMPRINC"];
 26+var DATE = Formula["DATE"];
 27+var DATEVALUE = function (dateString: string) : Date {
 28+  return new Date(dateString);
 29+};
 30+var DAY = Formula["DAY"];
 31+var DAYS = Formula["DAYS"];
 32+var DAYS360 = Formula["DAYS360"];
 33+var DB = Formula["DB"];
 34+var DDB = Formula["DDB"];
 35+var DEC2BIN = Formula["DEC2BIN"];
 36+var DEC2HEX = Formula["DEC2HEX"];
 37+var DEC2OCT = Formula["DEC2OCT"];
 38+var DEGREES = Formula["DEGREES"];
 39+var DEVSQ = Formula["DEVSQ"];
 40+var DOLLAR = Formula["DOLLAR"];
 41+var DOLLARDE = Formula["DOLLARDE"];
 42+var DOLLARFR = Formula["DOLLARFR"];
 43+var EDATE = function (start_date: Date, months) {
 44+  return moment(start_date).add(months, 'months').toDate();
 45+};
 46+var EFFECT = Formula["EFFECT"];
 47+var EOMONTH = function (start_date, months) {
 48+  var edate = moment(start_date).add(months, 'months');
 49+  return new Date(edate.year(), edate.month(), edate.daysInMonth());
 50+};
 51+var ERF = Formula["ERF"];
 52+var ERFC = Formula["ERFC"];
 53+var EXPONDIST = Formula["EXPONDIST"];
 54+var __COMPLEX = {
 55+  "F.DIST": Formula["FDIST"],
 56+  "F.INV": Formula["FINV"]
 57+};
 58+var FISHER = Formula["FISHER"];
 59+var FISHERINV = Formula["FISHERINV"];
 60+var IF = Formula["IF"];
 61+var SPLIT = Formula["SPLIT"];
 62+var SQRTPI = Formula["SQRTPI"];
 63+var SUMPRODUCT = Formula["SUMPRODUCT"];
 64+var SUMSQ = Formula["SUMSQ"];
 65+var SUMX2MY2 = Formula["SUMX2MY2"];
 66+var SUMX2PY2 = Formula["SUMX2PY2"];
 67+var TRUNC = Formula["TRUNC"];
 68+var YEARFRAC = Formula["YEARFRAC"];
 69 
 70 /**
 71  * Returns the a count of the number of numeric values in a dataset.
 72@@ -117,6 +170,32 @@ var COUNT = function (...values) : number {
 73   return count;
 74 };
 75 
 76+/**
 77+ * Returns a conditional count across a range.
 78+ * @param values[0] range - The range that is tested against criterion., value[1];
 79+ * @param values[1] criterion - The pattern or test to apply to range. If the range to check against contains text, this must be a
 80+ * string. It can be a comparison based string (e.g. "=1", "<1", ">=1") or it can be a wild-card string, in which *
 81+ * matches any number of characters, and ? matches the next character. Both ? and * can be escaped by placing a ~ in
 82+ * front of them. If it is neither, it will compared with values in the range using equality comparison.
 83+ * @returns {number}
 84+ * @constructor
 85+ */
 86+var COUNTIF = function (...values) {
 87+  checkArgumentsLength(values, 2);
 88+  var range = values[0];
 89+  var criteria = values[1];
 90+
 91+  var criteriaEvaluation = CriteriaFunctionFactory.createCriteriaFunction(criteria);
 92+
 93+  var count = 0;
 94+  for (var i = 0; i < range.length; i++) {
 95+    var x = range[i];
 96+    if (criteriaEvaluation(x)) {
 97+      count++;
 98+    }
 99+  }
100+  return count;
101+};
102 
103 /**
104  * Returns the a count of the number of values in a dataset.
105@@ -141,31 +220,6 @@ var COUNTA = function (...values) : number {
106   return count;
107 };
108 
109-
110-var COUNTIF = Formula["COUNTIF"];
111-var COUNTIFS = Formula["COUNTIFS"];
112-var COUNTIN = Formula["COUNTIN"];
113-var COUNTUNIQUE = Formula["COUNTUNIQUE"];
114-var COVARIANCEP = Formula["COVARIANCEP"];
115-var COVARIANCES = Formula["COVARIANCES"];
116-var CSC = Formula["CSC"];
117-var CSCH = Formula["CSCH"];
118-var CUMIPMT = Formula["CUMIPMT"];
119-var CUMPRINC = Formula["CUMPRINC"];
120-var DATE = Formula["DATE"];
121-var DATEVALUE = function (dateString: string) : Date {
122-  return new Date(dateString);
123-};
124-var DAY = Formula["DAY"];
125-var DAYS = Formula["DAYS"];
126-var DAYS360 = Formula["DAYS360"];
127-var DB = Formula["DB"];
128-var DDB = Formula["DDB"];
129-var DEC2BIN = Formula["DEC2BIN"];
130-var DEC2HEX = Formula["DEC2HEX"];
131-var DEC2OCT = Formula["DEC2OCT"];
132-var DEGREES = Formula["DEGREES"];
133-
134 /**
135  * Compare two numeric values, returning 1 if they're equal.
136  * @param values[0] The first number to compare.
137@@ -181,29 +235,6 @@ var DELTA = function (...values) : number {
138   return valueToNumber(values[0]) === valueToNumber(values[1]) ? 1 : 0;
139 };
140 
141-var DEVSQ = Formula["DEVSQ"];
142-var DOLLAR = Formula["DOLLAR"];
143-var DOLLARDE = Formula["DOLLARDE"];
144-var DOLLARFR = Formula["DOLLARFR"];
145-var EDATE = function (start_date: Date, months) {
146-  return moment(start_date).add(months, 'months').toDate();
147-};
148-var EFFECT = Formula["EFFECT"];
149-var EOMONTH = function (start_date, months) {
150-  var edate = moment(start_date).add(months, 'months');
151-  return new Date(edate.year(), edate.month(), edate.daysInMonth());
152-};
153-var ERF = Formula["ERF"];
154-var ERFC = Formula["ERFC"];
155-var EXPONDIST = Formula["EXPONDIST"];
156-var __COMPLEX = {
157-  "F.DIST": Formula["FDIST"],
158-  "F.INV": Formula["FINV"]
159-};
160-var FISHER = Formula["FISHER"];
161-var FISHERINV = Formula["FISHERINV"];
162-var IF = Formula["IF"];
163-
164 /**
165  * Rounds a number to a certain number of decimal places according to standard rules.
166  * @param values[0] The value to round to places number of places.
167@@ -274,51 +305,8 @@ var SUMIF = function (...values) {
168   if (values.length === 3) {
169     sumRange = values[2];
170   }
171-  // Default criteria does nothing
172-  var criteriaEvaluation = function (x) : boolean {
173-    return false;
174-  };
175 
176-
177-  if (typeof criteria === "number") {
178-    criteriaEvaluation = function (x) : boolean {
179-      return x === criteria;
180-    };
181-  } else if (typeof criteria === "string") {
182-    // https://regex101.com/r/c2hxAZ/6
183-    var comparisonMatches = criteria.match(/(^<=|^>=|^=|^>|^<)\s*(-?[0-9]+([,.][0-9]+)?)\s*$/);
184-    if (comparisonMatches !== null && comparisonMatches.length >= 4 && comparisonMatches[2] !== undefined) {
185-      criteriaEvaluation = function (x) : boolean {
186-        return eval(x + criteria);
187-      };
188-      if (comparisonMatches[1] === "=") {
189-        criteriaEvaluation = function (x) : boolean {
190-          return eval(x + "===" + comparisonMatches[2]);
191-        };
192-      }
193-    } else if (criteria.match(/\*|\~\*|\?|\~\?/) !== null) {
194-      // Regular string
195-      var matches = criteria.match(/\*|\~\*|\?|\~\?/);
196-      if (matches !== null) {
197-        criteriaEvaluation = function (x) : boolean {
198-          try {
199-            // http://stackoverflow.com/questions/26246601/wildcard-string-comparison-in-javascript
200-            return new RegExp("^" + criteria.split("*").join(".*") + "$").test(x);
201-          } catch (e) {
202-            return false;
203-          }
204-        };
205-      } else {
206-        criteriaEvaluation = function (x) : boolean {
207-          return x === criteria;
208-        };
209-      }
210-    } else {
211-      criteriaEvaluation = function (x) : boolean {
212-        return x === criteria;
213-      };
214-    }
215-  }
216+  var criteriaEvaluation = CriteriaFunctionFactory.createCriteriaFunction(criteria);
217 
218   var sum = 0;
219   for (var i = 0; i < range.length; i++) {
220@@ -335,15 +323,6 @@ var SUMIF = function (...values) {
221   return sum;
222 };
223 
224-var SPLIT = Formula["SPLIT"];
225-var SQRTPI = Formula["SQRTPI"];
226-var SUMPRODUCT = Formula["SUMPRODUCT"];
227-var SUMSQ = Formula["SUMSQ"];
228-var SUMX2MY2 = Formula["SUMX2MY2"];
229-var SUMX2PY2 = Formula["SUMX2PY2"];
230-var TRUNC = Formula["TRUNC"];
231-var YEARFRAC = Formula["YEARFRAC"];
232-
233 /**
234  * Exclusive or or exclusive disjunction is a logical operation that outputs true only when inputs differ.
235  * @param values to check for exclusivity.
236diff --git a/src/RawFormulas/Utils.ts b/src/RawFormulas/Utils.ts
237index 4ae1be6..ae37b82 100644
238--- a/src/RawFormulas/Utils.ts
239+++ b/src/RawFormulas/Utils.ts
240@@ -192,6 +192,88 @@ function flatten(values: Array<any>) : Array<any> {
241   }, []);
242 }
243 
244+/**
245+ * Converts wild-card style expressions (in which * matches zero or more characters, and ? matches exactly one character)
246+ * to regular expressions. * and ? can be escaped by prefixing ~
247+ * @param c input
248+ * @returns {RegExp} resulting regex
249+ */
250+function wildCardRegex(c: string) {
251+  var a = c.split("~?");
252+  for (var i = 0; i < a.length; i++) {
253+    a[i] = a[i].split("?").join(".{1}");
254+  }
255+  var b = a.join("\\\?");
256+  var d = b.split("~*");
257+  for (var i = 0; i < d.length; i++) {
258+    d[i] = d[i].split("*").join(".*");
259+  }
260+  return new RegExp("^"+d.join(".*")+"$", "g");
261+}
262+
263+
264+/**
265+ * Creates a criteria function to evaluate elements in a range in an *IF function.
266+ */
267+class CriteriaFunctionFactory {
268+  /**
269+   * If the criteria is a number, use strict equality checking.
270+   * If the criteria is a string, check to see if it is a comparator.
271+   * If the criteria is a string, and it is not a comparator, check for regex.
272+   * If the criteria is a string and has not matched the above, finally use strict equality checking as a fallback.
273+   * If the criteria has not been set, default to false-returning criteria function.
274+   * @param criteria
275+   * @returns {(x:any)=>boolean}
276+   */
277+  static createCriteriaFunction(criteria: string) : Function {
278+    // Default criteria does nothing
279+    var criteriaEvaluation = function (x) : boolean {
280+      return false;
281+    };
282+
283+    if (typeof criteria === "number") {
284+      criteriaEvaluation = function (x) : boolean {
285+        return x === criteria;
286+      };
287+    } else if (typeof criteria === "string") {
288+      // https://regex101.com/r/c2hxAZ/6
289+      var comparisonMatches = criteria.match(/(^<=|^>=|^=|^>|^<)\s*(-?[0-9]+([,.][0-9]+)?)\s*$/);
290+      if (comparisonMatches !== null && comparisonMatches.length >= 4 && comparisonMatches[2] !== undefined) {
291+        criteriaEvaluation = function (x) : boolean {
292+          return eval(x + criteria);
293+        };
294+        if (comparisonMatches[1] === "=") {
295+          criteriaEvaluation = function (x) : boolean {
296+            return eval(x + "===" + comparisonMatches[2]);
297+          };
298+        }
299+      } else if (criteria.match(/\*|\~\*|\?|\~\?/) !== null) {
300+        // Regular string
301+        var matches = criteria.match(/\*|\~\*|\?|\~\?/);
302+        if (matches !== null) {
303+          criteriaEvaluation = function (x) : boolean {
304+            try {
305+              // http://stackoverflow.com/questions/26246601/wildcard-string-comparison-in-javascript
306+              return wildCardRegex(criteria).test(x);
307+            } catch (e) {
308+              return false;
309+            }
310+          };
311+        } else {
312+          criteriaEvaluation = function (x) : boolean {
313+            return x === criteria;
314+          };
315+        }
316+      } else {
317+        criteriaEvaluation = function (x) : boolean {
318+          return x === criteria;
319+        };
320+      }
321+    }
322+    return criteriaEvaluation;
323+  }
324+}
325+
326 
327 export {
328   stringValuesToZeros,
329@@ -205,5 +287,6 @@ export {
330   filterOutStringValues,
331   checkArgumentsAtLeastLength,
332   checkArgumentsAtWithin,
333-  checkArgumentsLength
334+  checkArgumentsLength,
335+  CriteriaFunctionFactory
336 }
337\ No newline at end of file
338diff --git a/tests/FormulasTest.ts b/tests/FormulasTest.ts
339index 8e805dd..b1c5356 100644
340--- a/tests/FormulasTest.ts
341+++ b/tests/FormulasTest.ts
342@@ -473,7 +473,41 @@ catchAndAssertEquals(function() {
343 }, ERRORS.NA_ERROR);
344 
345 
346+// Test COUNTIF
347 assertEquals(COUNTIF([1, 5, 10], ">4"), 2);
348+assertEquals(COUNTIF([1, 2, 2, 2, 2, 2, 2, 2], ">1"), 7);
349+assertEquals(COUNTIF([1, 5, 10], 5), 1);
350+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], 5), 4);
351+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], 10), 1);
352+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], ">5"), 1);
353+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], "=5"), 4);
354+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], "=10"), 1);
355+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], "=     10  "), 1);
356+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], ">0"), 6);
357+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], ">=5"), 5);
358+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], "<10"), 5);
359+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5, 44], "<=10"), 6);
360+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], ">4.99"), 5);
361+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], "<4.99"), 1);
362+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], "=     1.0.0  "), 0);
363+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], "=>5"), 0);
364+assertEquals(COUNTIF([1, 5, 5, 5, 10, 5], "==5"), 0);
365+assertEquals(COUNTIF(["mom", "pop", "dad", "etc", "boom"], "*o*"), 3);
366+assertEquals(COUNTIF(["mom", "pop", "dad", "etc", "mom"], "mom"), 2);
367+assertEquals(COUNTIF(["mom", "pop", "dad", "etc", "mom"], "?o?"), 3);
368+assertEquals(COUNTIF(["mom", "pop", "dad", "etc", "mom"], "???"), 5);
369+assertEquals(COUNTIF(["mom", "pop", "dad", "etc", "mom"], "????"), 0);
370+assertEquals(COUNTIF(["mom", "pop", "dad", "etc", "mom"], "?"), 0);
371+catchAndAssertEquals(function() {
372+  COUNTIF([0, 1, 0, 1]);
373+}, ERRORS.NA_ERROR);
374+catchAndAssertEquals(function() {
375+  COUNTIF();
376+}, ERRORS.NA_ERROR);
377+catchAndAssertEquals(function() {
378+  COUNTIF([], "=1", []);
379+}, ERRORS.NA_ERROR);
380+
381 
382 assertEquals(COUNTIFS([1, 5, 10], ">4", [1, 5, 10], ">4"), 2);
383 
384@@ -1127,6 +1161,11 @@ assertEquals(SUMIF(["mom", "pop", "pap"], "p*p", [1, 1, 1]), 2);
385 assertEquals(SUMIF(["mom", "pop", "pap"], "p*p", [1, 1, 1]), 2);
386 assertEquals(SUMIF(["mom", "pop", "pap"], "p*p", [1, 1,]), 1);
387 assertEquals(SUMIF(["pop", "pap"], "p*p", [1, 2, 4]), 3);
388+assertEquals(SUMIF(["mom", "pop", "dad", "etc", "boom"], "*o*", [1, 1, 1, 1, 1]), 3);
389+assertEquals(SUMIF(["mom", "pop", "dad", "etc", "mom"], "mom", [1, 1, 1, 1, 1]), 2);
390+assertEquals(SUMIF(["mom", "pop", "dad", "etc", "mom"], "?o?", [1, 1, 1, 1, 1]), 3);
391+assertEquals(SUMIF(["mom", "pop", "dad", "etc", "mom"], "???", [1, 1, 1, 1, 1]), 5);
392+assertEquals(SUMIF(["mom", "pop", "dad", "etc", "mom"], "????", [1, 1, 1, 1, 1]), 0);
393 assertEquals(SUMIF([0, 1, 0, 1], "=1", [1, 2, 4, 8]), 10);
394 catchAndAssertEquals(function() {
395   SUMIF([0, 1, 0, 1]);