spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
Added Formulas.PEARSON and Formulas.CORREL
author
Ben Vogt <[email protected]>
date
2017-02-20 17:43:17
stats
3 file(s) changed, 121 insertions(+), 8 deletions(-)
files
README.md
src/RawFormulas/RawFormulas.ts
tests/FormulasTest.ts
  1diff --git a/README.md b/README.md
  2index 86093f8..1eace99 100644
  3--- a/README.md
  4+++ b/README.md
  5@@ -4,10 +4,6 @@ TypeScript implementation of a spreadsheet.
  6 ## TODO
  7 Things I should do.
  8 
  9-### Write tests for supported formulas.
 10-* Write more thorough tests for all formulas
 11-* Include fail state values for all formulas
 12-
 13 ### SUM and SUMA should be different, and I'm pretty sure they're currently the same.
 14 
 15 ### Date-Time issues
 16@@ -33,4 +29,7 @@ arbitrary javascript is executed in the client machine.
 17 ### Bring back missing Excel functions
 18 * COVARIANCEP
 19 * COVARIANCES
 20-* ...etc.
 21\ No newline at end of file
 22+* ...etc.
 23+
 24+### Refactor the way we construct and throw errors
 25+For example, the mis-matched argument length errors are all generated the same way.
 26\ No newline at end of file
 27diff --git a/src/RawFormulas/RawFormulas.ts b/src/RawFormulas/RawFormulas.ts
 28index f82d7f8..82f2adf 100644
 29--- a/src/RawFormulas/RawFormulas.ts
 30+++ b/src/RawFormulas/RawFormulas.ts
 31@@ -108,7 +108,6 @@ import * as ERRORS from "../Errors"
 32 var ACCRINT = Formula["ACCRINT"];
 33 var COMBIN = Formula["COMBIN"];
 34 var CONVERT = Formula["CONVERT"];
 35-var CORREL = Formula["CORREL"];
 36 var CUMIPMT = Formula["CUMIPMT"];
 37 var CUMPRINC = Formula["CUMPRINC"];
 38 var DATE = Formula["DATE"];
 39@@ -134,6 +133,92 @@ var __COMPLEX = {
 40 };
 41 var YEARFRAC = Formula["YEARFRAC"];
 42 
 43+/**
 44+ * Calculates r, the Pearson product-moment correlation coefficient of a dataset. Any text encountered in the arguments
 45+ * will be ignored. CORREL is synonymous with PEARSON.
 46+ * @param values[0] data_y - The range representing the array or matrix of dependent data.
 47+ * @param values[1] data_x - The range representing the array or matrix of independent data.
 48+ * @returns {number} the Pearson product-moment correlation coefficient.
 49+ * @constructor
 50+ */
 51+var CORREL = function (...values) : number {
 52+  function stdev(arr, flag) {
 53+    return Math.sqrt(variance(arr, flag));
 54+  }
 55+  function variance(arr, flag) {
 56+    if ((arr.length - (flag ? 1 : 0)) === 0) {
 57+      throw new CellError(ERRORS.DIV_ZERO_ERROR, "Evaluation of function CORREL caused a divide by zero error.");
 58+    }
 59+    return sumsqerr(arr) / (arr.length - (flag ? 1 : 0));
 60+  }
 61+  function sum(arr) {
 62+    var sum = 0;
 63+    var i = arr.length;
 64+    while (--i >= 0) {
 65+      sum += arr[i];
 66+    }
 67+    return sum;
 68+  }
 69+  function mean(arr) {
 70+    return sum(arr) / arr.length;
 71+  }
 72+  function sumsqerr(arr) {
 73+    var m = mean(arr);
 74+    var sum = 0;
 75+    var i = arr.length;
 76+    var tmp;
 77+    while (--i >= 0) {
 78+      tmp = arr[i] - m;
 79+      sum += tmp * tmp;
 80+    }
 81+    return sum;
 82+  }
 83+  function covariance(arr1, arr2) {
 84+    var u = mean(arr1);
 85+    var v = mean(arr2);
 86+    var arr1Len = arr1.length;
 87+    var sq_dev = new Array(arr1Len);
 88+    for (var i = 0; i < arr1Len; i++) {
 89+      sq_dev[i] = (arr1[i] - u) * (arr2[i] - v);
 90+    }
 91+    if ((arr1Len - 1) === 0) {
 92+      throw new CellError(ERRORS.DIV_ZERO_ERROR, "Evaluation of function CORREL caused a divide by zero error.");
 93+    }
 94+    return sum(sq_dev) / (arr1Len - 1);
 95+  }
 96+  ArgsChecker.checkLength(values, 2);
 97+  if (!Array.isArray(values[0])) {
 98+    values[0] = [values[0]];
 99+  }
100+  if (!Array.isArray(values[1])) {
101+    values[1] = [values[1]];
102+  }
103+  if (values[0].length !== values[1].length) {
104+    throw new CellError(ERRORS.NA_ERROR, "CORREL has mismatched argument count " + values[0] + " vs " + values[1] + ".");
105+  }
106+  var arr1 = Filter.filterOutNonNumberValues(Filter.flattenAndThrow(values[0]));
107+  var arr2 = Filter.filterOutNonNumberValues(Filter.flattenAndThrow(values[1]));
108+  var stdevArr1 = stdev(arr1, 1);
109+  var stdevArr2 = stdev(arr2, 1);
110+  if (stdevArr1 === 0 || stdevArr2 === 0) {
111+    throw new CellError(ERRORS.DIV_ZERO_ERROR, "Evaluation of function CORREL caused a divide by zero error.");
112+  }
113+  return covariance(arr1, arr2) / stdev(arr1, 1) / stdev(arr2, 1);
114+};
115+
116+/**
117+ * Calculates r, the Pearson product-moment correlation coefficient of a dataset. Any text encountered in the arguments
118+ * will be ignored. PEARSON is synonymous with CORREL.
119+ * @param values[0] data_y - The range representing the array or matrix of dependent data.
120+ * @param values[1] data_x - The range representing the array or matrix of independent data.
121+ * @returns {number} the Pearson product-moment correlation coefficient.
122+ * @constructor
123+ */
124+var PEARSON = function (...values) {
125+  return CORREL.apply(this, values);
126+};
127+
128+
129 export {
130   __COMPLEX,
131 
132@@ -163,6 +248,7 @@ export {
133   CONCATENATE,
134   CONVERT,
135   CORREL,
136+  PEARSON,
137   COS,
138   PI,
139   COSH,
140diff --git a/tests/FormulasTest.ts b/tests/FormulasTest.ts
141index 32737b5..a9df7a4 100644
142--- a/tests/FormulasTest.ts
143+++ b/tests/FormulasTest.ts
144@@ -1,6 +1,6 @@
145 import { ABS, ACCRINT, ACOS, ACOSH, ACOTH, AND, ARABIC, ASIN, ASINH, ATAN, ATAN2, ATANH, AVEDEV, AVERAGE,
146     AVERAGEA, AVERAGEIF, BIN2DEC, BIN2HEX, BIN2OCT, CEILING,
147-    CHAR, CODE, COMBIN, CONCATENATE, CONVERT,
148+    CHAR, CODE, COMBIN, CONCATENATE, CONVERT, PEARSON,
149     CORREL, COS, PI, COSH, COT, COTH, COUNT, COUNTA, COUNTIF, COUNTIFS, COUNTUNIQUE,
150     CUMIPMT, CUMPRINC, DATE, DATEVALUE, DAY, DAYS, DAYS360,
151     DB, DDB, DEC2BIN, DEC2HEX, DEC2OCT, DEGREES, DELTA, DEVSQ, DOLLAR, DOLLARDE, DOLLARFR, EDATE,
152@@ -442,7 +442,35 @@ catchAndAssertEquals(function() {
153 
154 assertEquals(CONVERT(5.1, "mm", "m"), 0.0050999999999999995);
155 
156+
157+// Test CORREL
158 assertEquals(CORREL([9, 5],[10, 4]), 1);
159+assertEquals(CORREL([10, 5, 16],[9, 3, 22]), 0.9876779373054069);
160+catchAndAssertEquals(function() {
161+  CORREL(5, 5);
162+}, ERRORS.DIV_ZERO_ERROR);
163+catchAndAssertEquals(function() {
164+  CORREL([9, true], [5, true]);
165+}, ERRORS.DIV_ZERO_ERROR);
166+catchAndAssertEquals(function() {
167+  CORREL([9, "10"], [5, "10"]);
168+}, ERRORS.DIV_ZERO_ERROR);
169+catchAndAssertEquals(function() {
170+  CORREL([9], [5]);
171+}, ERRORS.DIV_ZERO_ERROR);
172+catchAndAssertEquals(function() {
173+  CORREL();
174+}, ERRORS.NA_ERROR);
175+catchAndAssertEquals(function() {
176+  CORREL([9, 5]);
177+}, ERRORS.NA_ERROR);
178+catchAndAssertEquals(function() {
179+  CORREL([9, 5],[10]);
180+}, ERRORS.NA_ERROR);
181+
182+
183+// Test PEARSON (same as CORREL)
184+assertEquals(PEARSON([9, 5],[10, 4]), 1);
185 
186 
187 // Test COS