spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
[PERCENTILE, QUARTILE] formulas added and tested
author
Ben Vogt <[email protected]>
date
2017-06-13 00:37:43
stats
13 file(s) changed, 240 insertions(+), 8 deletions(-)
files
DOCS.md
TODO.md
dist/Formulas/AllFormulas.js
dist/Formulas/Math.js
dist/Formulas/Statistical.js
dist/Utilities/Filter.js
dist/Utilities/MathHelpers.js
src/Formulas/AllFormulas.ts
src/Formulas/Statistical.ts
src/Utilities/Filter.ts
src/Utilities/MathHelpers.ts
tests/Formulas/StatisticalTest.ts
tests/SheetFormulaTest.ts
  1diff --git a/DOCS.md b/DOCS.md
  2index d1e2ff3..b17242d 100644
  3--- a/DOCS.md
  4+++ b/DOCS.md
  5@@ -1327,6 +1327,24 @@
  6 @returns {number} number of values in a dataset. 
  7 @constructor
  8 ```
  9+
 10+### ERCENTILE 
 11+
 12+```
 13+  Returns the value at a given percentile of a set of data. 
 14+@param data -  The array or range containing the dataset to consider. 
 15+@param percent - percentile to be calculated and returned. 
 16+@returns {number} 
 17+@constructor
 18+```
 19+
 20+### QUARTILE 
 21+
 22+```
 23+  Returns a value nearest to a specified quartile of a set of data. 
 24+@param data -  The array or range containing the set of data to consider. 
 25+@param quartile - Which quartile value to return. 0 returns 0
 26+```
 27 ## Text
 28 
 29 
 30diff --git a/TODO.md b/TODO.md
 31index 99c1cab..63eceeb 100644
 32--- a/TODO.md
 33+++ b/TODO.md
 34@@ -89,14 +89,12 @@ For example 64 tbs to a qt.
 35 * NORMINV
 36 * NORMSDIST
 37 * NORMSINV
 38-* PERCENTILE
 39 * PERCENTRANK
 40 * PERCENTRANK.EXC
 41 * PERCENTRANK.INC
 42 * PERMUT
 43 * POISSON
 44 * PROB
 45-* QUARTILE
 46 * RANK
 47 * RANK.AVG
 48 * RANK.EQ
 49diff --git a/dist/Formulas/AllFormulas.js b/dist/Formulas/AllFormulas.js
 50index 0b91a1c..f0f9b0c 100644
 51--- a/dist/Formulas/AllFormulas.js
 52+++ b/dist/Formulas/AllFormulas.js
 53@@ -116,6 +116,8 @@ exports.MAX = Statistical_1.MAX;
 54 exports.MAXA = Statistical_1.MAXA;
 55 exports.MIN = Statistical_1.MIN;
 56 exports.MINA = Statistical_1.MINA;
 57+exports.QUARTILE = Statistical_1.QUARTILE;
 58+exports.PERCENTILE = Statistical_1.PERCENTILE;
 59 var Text_1 = require("./Text");
 60 exports.ARABIC = Text_1.ARABIC;
 61 exports.CHAR = Text_1.CHAR;
 62diff --git a/dist/Formulas/Math.js b/dist/Formulas/Math.js
 63index e393a95..a615443 100644
 64--- a/dist/Formulas/Math.js
 65+++ b/dist/Formulas/Math.js
 66@@ -58,8 +58,8 @@ var LCM = function () {
 67 };
 68 exports.LCM = LCM;
 69 /**
 70- *
 71- * @param value
 72+ * Returns the the logarithm of a specified Gamma function, base e (Euler's number).
 73+ * @param value - The input number. The natural logarithm of Gamma (value) will be returned. Must be positive.
 74  * @returns {number}
 75  * @constructor
 76  */
 77diff --git a/dist/Formulas/Statistical.js b/dist/Formulas/Statistical.js
 78index 8ea559e..5d6b304 100644
 79--- a/dist/Formulas/Statistical.js
 80+++ b/dist/Formulas/Statistical.js
 81@@ -527,3 +527,59 @@ var COUNTA = function () {
 82     return count;
 83 };
 84 exports.COUNTA = COUNTA;
 85+/**
 86+ * Returns the value at a given percentile of a set of data.
 87+ * @param data -  The array or range containing the dataset to consider.
 88+ * @param percent - percentile to be calculated and returned.
 89+ * @returns {number}
 90+ * @constructor
 91+ */
 92+var PERCENTILE = function (data, percent) {
 93+    ArgsChecker_1.ArgsChecker.checkLength(arguments, 2, "PERCENTILE");
 94+    var p = TypeConverter_1.TypeConverter.firstValueAsNumber(percent);
 95+    if (p < 0 || p > 1) {
 96+        throw new Errors_1.NumError("Function PERCENTILE parameter 2 value " + p + " is out of range.");
 97+    }
 98+    var range = Filter_1.Filter.flattenAndThrow(data).sort(function (a, b) {
 99+        return a - b;
100+    }).map(function (value) {
101+        return TypeConverter_1.TypeConverter.valueToNumber(value);
102+    });
103+    var n = range.length;
104+    var l = p * (n - 1);
105+    var fl = Math.floor(l);
106+    return MathHelpers_1.cleanFloat((l === fl) ? range[l] : range[fl] + (l - fl) * (range[fl + 1] - range[fl]));
107+};
108+exports.PERCENTILE = PERCENTILE;
109+/**
110+ * Returns a value nearest to a specified quartile of a set of data.
111+ * @param data -  The array or range containing the set of data to consider.
112+ * @param quartile - Which quartile value to return. 0 returns 0% mark, 1 returns 25% mark, 2 returns 50% mark, 3
113+ * returns 75% mark, 4 returns 100% mark.
114+ * @constructor
115+ */
116+var QUARTILE = function (data, quartile) {
117+    ArgsChecker_1.ArgsChecker.checkLength(arguments, 2, "QUARTILE");
118+    var q = TypeConverter_1.TypeConverter.firstValueAsNumber(quartile);
119+    if (q < 0 || q > 4) {
120+        throw new Errors_1.NumError("Function QUARTILE parameter 2 value " + q + " is out of range.");
121+    }
122+    var range = Filter_1.Filter.flattenAndThrow(data).sort(function (a, b) {
123+        return a - b;
124+    }).map(function (value) {
125+        return TypeConverter_1.TypeConverter.valueToNumber(value);
126+    });
127+    switch (q) {
128+        case 0:
129+            return PERCENTILE(range, 0);
130+        case 1:
131+            return PERCENTILE(range, 0.25);
132+        case 2:
133+            return PERCENTILE(range, 0.5);
134+        case 3:
135+            return PERCENTILE(range, 0.75);
136+        case 4:
137+            return PERCENTILE(range, 1);
138+    }
139+};
140+exports.QUARTILE = QUARTILE;
141diff --git a/dist/Utilities/Filter.js b/dist/Utilities/Filter.js
142index 43f553f..e565e62 100644
143--- a/dist/Utilities/Filter.js
144+++ b/dist/Utilities/Filter.js
145@@ -40,6 +40,9 @@ var Filter = (function () {
146      * @returns {Array} flattened array
147      */
148     Filter.flattenAndThrow = function (values) {
149+        if (values.length === 0) {
150+            throw new Errors_1.RefError("Reference does not exist.");
151+        }
152         return values.reduce(function (flat, toFlatten) {
153             if (Array.isArray(toFlatten) && toFlatten.length === 0) {
154                 throw new Errors_1.RefError("Reference does not exist.");
155diff --git a/dist/Utilities/MathHelpers.js b/dist/Utilities/MathHelpers.js
156index a217655..fde526a 100644
157--- a/dist/Utilities/MathHelpers.js
158+++ b/dist/Utilities/MathHelpers.js
159@@ -357,3 +357,13 @@ function betafn(x, y) {
160     return (x + y > 170) ? Math.exp(betaln(x, y)) : gammafn(x) * gammafn(y) / gammafn(x + y);
161 }
162 exports.betafn = betafn;
163+/**
164+ * Cleans a float number.
165+ * @param n - number to clean
166+ * @returns {number} -  clean number
167+ */
168+function cleanFloat(n) {
169+    var power = Math.pow(10, 14);
170+    return Math.round(n * power) / power;
171+}
172+exports.cleanFloat = cleanFloat;
173diff --git a/src/Formulas/AllFormulas.ts b/src/Formulas/AllFormulas.ts
174index 485ef19..ad29f1b 100644
175--- a/src/Formulas/AllFormulas.ts
176+++ b/src/Formulas/AllFormulas.ts
177@@ -120,7 +120,9 @@ import {
178   MAX,
179   MAXA,
180   MIN,
181-  MINA
182+  MINA,
183+  QUARTILE,
184+  PERCENTILE
185 } from "./Statistical";
186 import {
187   ARABIC,
188@@ -307,5 +309,7 @@ export {
189   GCD,
190   TRIM,
191   LCM,
192-  GAMMALN
193+  GAMMALN,
194+  QUARTILE,
195+  PERCENTILE
196 }
197\ No newline at end of file
198diff --git a/src/Formulas/Statistical.ts b/src/Formulas/Statistical.ts
199index e849178..d11d52b 100644
200--- a/src/Formulas/Statistical.ts
201+++ b/src/Formulas/Statistical.ts
202@@ -23,6 +23,7 @@ import {
203   inv,
204   pdf,
205   stdev,
206+  cleanFloat
207 } from "../Utilities/MathHelpers";
208 
209 
210@@ -506,6 +507,68 @@ var COUNTA = function (...values) : number {
211   return count;
212 };
213 
214+
215+/**
216+ * Returns the value at a given percentile of a set of data.
217+ * @param data -  The array or range containing the dataset to consider.
218+ * @param percent - percentile to be calculated and returned.
219+ * @returns {number}
220+ * @constructor
221+ */
222+var PERCENTILE =  function (data, percent) {
223+  ArgsChecker.checkLength(arguments, 2, "PERCENTILE");
224+  var p = TypeConverter.firstValueAsNumber(percent);
225+  if (p < 0 || p > 1) {
226+    throw new NumError("Function PERCENTILE parameter 2 value " + p + " is out of range.");
227+  }
228+  var range = Filter.flattenAndThrow(data).sort(function (a, b) {
229+    return a - b;
230+  }).map(function (value) {
231+    return TypeConverter.valueToNumber(value);
232+  });
233+
234+  var n = range.length;
235+  var l = p * (n - 1);
236+  var fl = Math.floor(l);
237+  return cleanFloat((l === fl) ? range[l] : range[fl] + (l - fl) * (range[fl + 1] - range[fl]));
238+};
239+
240+
241+/**
242+ * Returns a value nearest to a specified quartile of a set of data.
243+ * @param data -  The array or range containing the set of data to consider.
244+ * @param quartile - Which quartile value to return. 0 returns 0% mark, 1 returns 25% mark, 2 returns 50% mark, 3
245+ * returns 75% mark, 4 returns 100% mark.
246+ * @constructor
247+ */
248+var QUARTILE = function (data, quartile) {
249+  ArgsChecker.checkLength(arguments, 2, "QUARTILE");
250+  var q = TypeConverter.firstValueAsNumber(quartile);
251+  if (q < 0 || q > 4) {
252+    throw new NumError("Function QUARTILE parameter 2 value " + q + " is out of range.");
253+  }
254+
255+
256+  var range = Filter.flattenAndThrow(data).sort(function (a, b) {
257+    return a - b;
258+  }).map(function (value) {
259+    return TypeConverter.valueToNumber(value);
260+  });
261+
262+  switch (q) {
263+    case 0:
264+      return PERCENTILE(range, 0);
265+    case 1:
266+      return PERCENTILE(range, 0.25);
267+    case 2:
268+      return PERCENTILE(range, 0.5);
269+    case 3:
270+      return PERCENTILE(range, 0.75);
271+    case 4:
272+      return PERCENTILE(range, 1);
273+  }
274+};
275+
276 export {
277   AVERAGE,
278   AVERAGEA,
279@@ -525,5 +588,7 @@ export {
280   MAX,
281   MAXA,
282   MIN,
283-  MINA
284+  MINA,
285+  QUARTILE,
286+  PERCENTILE
287 }
288\ No newline at end of file
289diff --git a/src/Utilities/Filter.ts b/src/Utilities/Filter.ts
290index f26c83a..676ea81 100644
291--- a/src/Utilities/Filter.ts
292+++ b/src/Utilities/Filter.ts
293@@ -40,6 +40,9 @@ class Filter {
294    * @returns {Array} flattened array
295    */
296   static flattenAndThrow(values: Array<any>) : Array<any> {
297+    if (values.length === 0) {
298+      throw new RefError("Reference does not exist.");
299+    }
300     return values.reduce(function (flat, toFlatten) {
301       if (Array.isArray(toFlatten) && toFlatten.length === 0) {
302         throw new RefError("Reference does not exist.");
303diff --git a/src/Utilities/MathHelpers.ts b/src/Utilities/MathHelpers.ts
304index 44d4689..95efb62 100644
305--- a/src/Utilities/MathHelpers.ts
306+++ b/src/Utilities/MathHelpers.ts
307@@ -361,6 +361,16 @@ function betafn(x, y) {
308   return (x + y > 170) ? Math.exp(betaln(x, y)) : gammafn(x) * gammafn(y) / gammafn(x + y);
309 }
310 
311+/**
312+ * Cleans a float number.
313+ * @param n - number to clean
314+ * @returns {number} -  clean number
315+ */
316+function cleanFloat(n) {
317+  var power = Math.pow(10, 14);
318+  return Math.round(n * power) / power;
319+}
320+
321 export {
322   betacf,
323   betafn,
324@@ -378,5 +388,6 @@ export {
325   stdev,
326   sum,
327   sumsqerr,
328-  variance
329+  variance,
330+  cleanFloat
331 }
332\ No newline at end of file
333diff --git a/tests/Formulas/StatisticalTest.ts b/tests/Formulas/StatisticalTest.ts
334index 44db1f8..3921bb2 100644
335--- a/tests/Formulas/StatisticalTest.ts
336+++ b/tests/Formulas/StatisticalTest.ts
337@@ -17,7 +17,9 @@ import {
338   MAX,
339   MAXA,
340   MIN,
341-  MINA
342+  MINA,
343+  QUARTILE,
344+  PERCENTILE
345 } from "../../src/Formulas/Statistical";
346 import * as ERRORS from "../../src/Errors";
347 import {
348@@ -424,3 +426,51 @@ test("F.DIST", function(){
349     FDIST$LEFTTAILED.apply(this, []);
350   }, ERRORS.NA_ERROR);
351 });
352+
353+
354+test("PERCENTILE", function () {
355+  assertEquals(PERCENTILE([72, 57, 66, 92, 32, 17, 146], 0.5), 66);
356+  assertEquals(PERCENTILE([72, 57, 66, 92, 32, 17, 146], 0.2), 37.00000000000001);
357+  assertEquals(PERCENTILE([72, 57, 66, 92, 32, 17, 146], 0.1), 26);
358+  assertEquals(PERCENTILE([72, 57, 66, 92, 32, 17, 146], 0), 17);
359+  assertEquals(PERCENTILE([72], 0.2), 72);
360+  assertEquals(PERCENTILE([72], 0), 72);
361+  assertEquals(PERCENTILE([72], 1), 72);
362+  assertEquals(PERCENTILE([72], 0.1111), 72);
363+  catchAndAssertEquals(function() {
364+    PERCENTILE.apply(this, [[], 0]);
365+  }, ERRORS.REF_ERROR);
366+  catchAndAssertEquals(function() {
367+    PERCENTILE.apply(this, [[10], 0, 10]);
368+  }, ERRORS.NA_ERROR);
369+  catchAndAssertEquals(function() {
370+    PERCENTILE.apply(this, [[10]]);
371+  }, ERRORS.NA_ERROR);
372+  catchAndAssertEquals(function() {
373+    PERCENTILE.apply(this, [[10], -0.1]);
374+  }, ERRORS.NUM_ERROR);
375+  catchAndAssertEquals(function() {
376+    PERCENTILE.apply(this, [[10], 1.1]);
377+  }, ERRORS.NUM_ERROR);
378+});
379+
380+
381+test("QUARTILE", function(){
382+  assertEquals(QUARTILE([1, 2, 3, 4], 0), 1);
383+  assertEquals(QUARTILE([1, 2, 3, 4], 1), 1.75);
384+  assertEquals(QUARTILE([1, 2, 3, 4], 2), 2.5);
385+  assertEquals(QUARTILE([1, 2, 3, 4], 3), 3.25);
386+  assertEquals(QUARTILE([1, 2, 3, 4], 4), 4);
387+  catchAndAssertEquals(function() {
388+    QUARTILE.apply(this, [[1, 2, 3, 4], 5]);
389+  }, ERRORS.NUM_ERROR);
390+  catchAndAssertEquals(function() {
391+    QUARTILE.apply(this, [[1, 2, 3, 4], -1]);
392+  }, ERRORS.NUM_ERROR);
393+  catchAndAssertEquals(function() {
394+    QUARTILE.apply(this, [[1, 2, 3, 4]]);
395+  }, ERRORS.NA_ERROR);
396+  catchAndAssertEquals(function() {
397+    QUARTILE.apply(this, [[1, 2, 3, 4], 5, 7]);
398+  }, ERRORS.NA_ERROR);
399+});
400\ No newline at end of file
401diff --git a/tests/SheetFormulaTest.ts b/tests/SheetFormulaTest.ts
402index 824b510..b0c1328 100644
403--- a/tests/SheetFormulaTest.ts
404+++ b/tests/SheetFormulaTest.ts
405@@ -259,6 +259,14 @@ test("Sheet GAMMALN", function(){
406   assertFormulaEquals('=GAMMALN(4.5)', 2.453736570842444);
407 });
408 
409+test("Sheet PERCENTILE", function(){
410+  assertFormulaEquals('=PERCENTILE([10], 0)', 10);
411+});
412+
413+test("Sheet QUARTILE", function(){
414+  assertFormulaEquals('=QUARTILE([1, 2, 3, 4], 0)', 1);
415+});
416+
417 test("Sheet DELTA", function(){
418   assertFormulaEquals('=DELTA(2, 2)', 1);
419 });