spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
[STDEV, STDEVA] formulas added and tested
author
Ben Vogt <[email protected]>
date
2017-06-14 00:49:05
stats
8 file(s) changed, 184 insertions(+), 5 deletions(-)
files
DOCS.md
TODO.md
dist/Formulas/AllFormulas.js
dist/Formulas/Statistical.js
src/Formulas/AllFormulas.ts
src/Formulas/Statistical.ts
tests/Formulas/StatisticalTest.ts
tests/SheetFormulaTest.ts
  1diff --git a/DOCS.md b/DOCS.md
  2index bd3b10e..f0e64df 100644
  3--- a/DOCS.md
  4+++ b/DOCS.md
  5@@ -1382,6 +1382,24 @@
  6 @param quartile - Which quartile value to return. 0 returns 0 percent mark, 1 returns 25 percent mark, 2 returns 50 percent mark, 3 returns 75 percent mark, 4 returns 100 percent mark. 
  7 @constructor
  8 ```
  9+
 10+### STDEV 
 11+
 12+```
 13+  Calculates the standard deviation of a range, ignoring string values, regardless of whether they can be converted to numbers. 
 14+@param values - Range of sample 
 15+@returns {number} 
 16+@constructor
 17+```
 18+
 19+### STDEVA 
 20+
 21+```
 22+  Calculcates the standard deviation of a range, converting string values to numbers, if possible. If a value cannot be converted to a number, formula will throw a value error. 
 23+@param values - Range of sample. 
 24+@returns {number} 
 25+@constructor
 26+```
 27 ## Text
 28 
 29 
 30diff --git a/TODO.md b/TODO.md
 31index a41d6d5..18d12e5 100644
 32--- a/TODO.md
 33+++ b/TODO.md
 34@@ -25,7 +25,7 @@ For example 64 tbs to a qt.
 35 
 36 ### Formulas to write
 37 
 38-* ERROR.TYPE
 39+* ERROR.TYPE - Requires changes to parser.js
 40 * ISBLANK - May require changes to parser.js
 41 * ISEMAIL
 42 * ISERR
 43@@ -99,8 +99,6 @@ For example 64 tbs to a qt.
 44 * SLOPE
 45 * SMALL
 46 * STANDARDIZE
 47-* STDEV
 48-* STDEVA
 49 * STDEVP
 50 * STDEVPA
 51 * STEYX
 52diff --git a/dist/Formulas/AllFormulas.js b/dist/Formulas/AllFormulas.js
 53index d7ec24f..9a8bc6a 100644
 54--- a/dist/Formulas/AllFormulas.js
 55+++ b/dist/Formulas/AllFormulas.js
 56@@ -122,6 +122,8 @@ exports.MIN = Statistical_1.MIN;
 57 exports.MINA = Statistical_1.MINA;
 58 exports.QUARTILE = Statistical_1.QUARTILE;
 59 exports.PERCENTILE = Statistical_1.PERCENTILE;
 60+exports.STDEV = Statistical_1.STDEV;
 61+exports.STDEVA = Statistical_1.STDEVA;
 62 var Text_1 = require("./Text");
 63 exports.ARABIC = Text_1.ARABIC;
 64 exports.CHAR = Text_1.CHAR;
 65diff --git a/dist/Formulas/Statistical.js b/dist/Formulas/Statistical.js
 66index 7cafe7c..78e3a3b 100644
 67--- a/dist/Formulas/Statistical.js
 68+++ b/dist/Formulas/Statistical.js
 69@@ -583,3 +583,56 @@ var QUARTILE = function (data, quartile) {
 70     }
 71 };
 72 exports.QUARTILE = QUARTILE;
 73+/**
 74+ * Calculates the standard deviation of a range, ignoring string values, regardless of whether they can be converted to
 75+ * numbers.
 76+ * @param values - Range of sample
 77+ * @returns {number}
 78+ * @constructor
 79+ */
 80+var STDEV = function () {
 81+    var values = [];
 82+    for (var _i = 0; _i < arguments.length; _i++) {
 83+        values[_i] = arguments[_i];
 84+    }
 85+    ArgsChecker_1.ArgsChecker.checkAtLeastLength(arguments, 1, "STDEV");
 86+    var range = Filter_1.Filter.flattenAndThrow(values);
 87+    var n = range.length;
 88+    var sigma = 0;
 89+    var count = 0;
 90+    var mean = AVERAGE(range);
 91+    for (var i = 0; i < n; i++) {
 92+        var value = TypeConverter_1.TypeConverter.firstValue(range[i]);
 93+        if (typeof value !== "string") {
 94+            sigma += Math.pow(TypeConverter_1.TypeConverter.valueToNumber(value) - mean, 2);
 95+            count++;
 96+        }
 97+    }
 98+    return Math.sqrt(sigma / (count - 1));
 99+};
100+exports.STDEV = STDEV;
101+/**
102+ * Calculcates the standard deviation of a range, converting string values to numbers, if possible. If a value cannot
103+ * be converted to a number, formula will throw a value error.
104+ * @param values - Range of sample.
105+ * @returns {number}
106+ * @constructor
107+ */
108+var STDEVA = function () {
109+    var values = [];
110+    for (var _i = 0; _i < arguments.length; _i++) {
111+        values[_i] = arguments[_i];
112+    }
113+    ArgsChecker_1.ArgsChecker.checkAtLeastLength(arguments, 1, "STDEVA");
114+    var range = Filter_1.Filter.flattenAndThrow(values).map(function (value) {
115+        return TypeConverter_1.TypeConverter.firstValueAsNumber(value);
116+    });
117+    var n = range.length;
118+    var sigma = 0;
119+    var m = MathHelpers_1.mean(range);
120+    for (var i = 0; i < n; i++) {
121+        sigma += Math.pow(range[i] - m, 2);
122+    }
123+    return Math.sqrt(sigma / (n - 1));
124+};
125+exports.STDEVA = STDEVA;
126diff --git a/src/Formulas/AllFormulas.ts b/src/Formulas/AllFormulas.ts
127index e058e2c..cb81a57 100644
128--- a/src/Formulas/AllFormulas.ts
129+++ b/src/Formulas/AllFormulas.ts
130@@ -126,7 +126,9 @@ import {
131   MIN,
132   MINA,
133   QUARTILE,
134-  PERCENTILE
135+  PERCENTILE,
136+  STDEV,
137+  STDEVA
138 } from "./Statistical";
139 import {
140   ARABIC,
141@@ -319,5 +321,7 @@ export {
142   PRODUCT,
143   QUOTIENT,
144   UPLUS,
145-  UMINUS
146+  UMINUS,
147+  STDEV,
148+  STDEVA
149 }
150\ No newline at end of file
151diff --git a/src/Formulas/Statistical.ts b/src/Formulas/Statistical.ts
152index 5d6fcf0..308db54 100644
153--- a/src/Formulas/Statistical.ts
154+++ b/src/Formulas/Statistical.ts
155@@ -23,7 +23,8 @@ import {
156   inv,
157   pdf,
158   stdev,
159-  cleanFloat
160+  cleanFloat,
161+  mean
162 } from "../Utilities/MathHelpers";
163 
164 
165@@ -569,6 +570,53 @@ var QUARTILE = function (data, quartile) {
166   }
167 };
168 
169+
170+/**
171+ * Calculates the standard deviation of a range, ignoring string values, regardless of whether they can be converted to
172+ * numbers.
173+ * @param values - Range of sample
174+ * @returns {number}
175+ * @constructor
176+ */
177+var STDEV = function (...values) {
178+  ArgsChecker.checkAtLeastLength(arguments, 1, "STDEV");
179+  var range = Filter.flattenAndThrow(values);
180+  var n = range.length;
181+  var sigma = 0;
182+  var count = 0;
183+  var mean = AVERAGE(range);
184+  for (var i = 0; i < n; i++) {
185+    var value = TypeConverter.firstValue(range[i]);
186+    if (typeof value !== "string") {
187+      sigma += Math.pow(TypeConverter.valueToNumber(value) - mean, 2);
188+      count++;
189+    }
190+  }
191+  return Math.sqrt(sigma / (count - 1));
192+};
193+
194+
195+/**
196+ * Calculcates the standard deviation of a range, converting string values to numbers, if possible. If a value cannot
197+ * be converted to a number, formula will throw a value error.
198+ * @param values - Range of sample.
199+ * @returns {number}
200+ * @constructor
201+ */
202+var STDEVA = function (...values) {
203+  ArgsChecker.checkAtLeastLength(arguments, 1, "STDEVA");
204+  var range = Filter.flattenAndThrow(values).map(function (value) {
205+    return TypeConverter.firstValueAsNumber(value);
206+  });
207+  var n = range.length;
208+  var sigma = 0;
209+  var m = mean(range);
210+  for (var i = 0; i < n; i++) {
211+    sigma += Math.pow(range[i] - m, 2);
212+  }
213+  return Math.sqrt(sigma / (n - 1));
214+};
215+
216 export {
217   AVERAGE,
218   AVERAGEA,
219@@ -590,5 +638,7 @@ export {
220   MIN,
221   MINA,
222   QUARTILE,
223-  PERCENTILE
224+  PERCENTILE,
225+  STDEV,
226+  STDEVA
227 }
228\ No newline at end of file
229diff --git a/tests/Formulas/StatisticalTest.ts b/tests/Formulas/StatisticalTest.ts
230index 3921bb2..e3444a3 100644
231--- a/tests/Formulas/StatisticalTest.ts
232+++ b/tests/Formulas/StatisticalTest.ts
233@@ -19,7 +19,9 @@ import {
234   MIN,
235   MINA,
236   QUARTILE,
237-  PERCENTILE
238+  PERCENTILE,
239+  STDEV,
240+  STDEVA
241 } from "../../src/Formulas/Statistical";
242 import * as ERRORS from "../../src/Errors";
243 import {
244@@ -473,4 +475,42 @@ test("QUARTILE", function(){
245   catchAndAssertEquals(function() {
246     QUARTILE.apply(this, [[1, 2, 3, 4], 5, 7]);
247   }, ERRORS.NA_ERROR);
248-});
249\ No newline at end of file
250+});
251+
252+
253+test("STDEV", function(){
254+  assertEquals(STDEV(1, 2, 3, 4, 5, 6, 7, "18281821"), 2.160246899469287);
255+  assertEquals(STDEV(1, 2, 3, 4, 5, 6, 7), 2.160246899469287);
256+  assertEquals(STDEV([1, 2, 3, 4, 5, 6, 7]), 2.160246899469287);
257+  assertEquals(STDEV(1, 2, 3, [4, 5], 6, 7), 2.160246899469287);
258+  assertEquals(STDEV(33, 44), 7.7781745930520225);
259+  assertEquals(STDEV(33, 44, 0, 1, 0, 1), 19.934057957843574);
260+  assertEquals(STDEV(33, 44, false, true, false, true), 19.934057957843574);
261+  catchAndAssertEquals(function() {
262+    STDEV();
263+  }, ERRORS.NA_ERROR);
264+  catchAndAssertEquals(function() {
265+    STDEV([10, 10, [], 10]);
266+  }, ERRORS.REF_ERROR);
267+});
268+
269+
270+test("STDEVA", function(){
271+  assertEquals(STDEVA(1, 2, 3, 4, 5, 6, 7, "123"), 42.12036324629692);
272+  assertEquals(STDEVA(1, 2, 3, 4, 5, 6, 7, 123), 42.12036324629692);
273+  assertEquals(STDEVA(1, 2, 3, 4, 5, 6, 7), 2.160246899469287);
274+  assertEquals(STDEVA([1, 2, 3, 4, 5, 6, 7]), 2.160246899469287);
275+  assertEquals(STDEVA(1, 2, 3, [4, 5], 6, 7), 2.160246899469287);
276+  assertEquals(STDEVA(33, 44), 7.7781745930520225);
277+  assertEquals(STDEVA(33, 44, 0, 1, 0, 1), 19.934057957843574);
278+  assertEquals(STDEVA(33, 44, false, true, false, true), 19.934057957843574);
279+  catchAndAssertEquals(function() {
280+    STDEVA(1, 2, 3, 4, 5, 6, 7, "string");
281+  }, ERRORS.VALUE_ERROR);
282+  catchAndAssertEquals(function() {
283+    STDEVA();
284+  }, ERRORS.NA_ERROR);
285+  catchAndAssertEquals(function() {
286+    STDEVA([10, 10, [], 10]);
287+  }, ERRORS.REF_ERROR);
288+});
289diff --git a/tests/SheetFormulaTest.ts b/tests/SheetFormulaTest.ts
290index d08e075..d41d9f2 100644
291--- a/tests/SheetFormulaTest.ts
292+++ b/tests/SheetFormulaTest.ts
293@@ -275,6 +275,14 @@ test("Sheet UMINUS", function(){
294   assertFormulaEquals('=UMINUS(8)', -8);
295 });
296 
297+test("Sheet STDEV", function(){
298+  assertFormulaEquals('=STDEV([33, 44])', 7.7781745930520225);
299+});
300+
301+test("Sheet STDEVA", function(){
302+  assertFormulaEquals('=STDEVA(33, 44)', 7.7781745930520225);
303+});
304+
305 test("Sheet PERCENTILE", function(){
306   assertFormulaEquals('=PERCENTILE([10], 0)', 10);
307 });