commit
message
Added Formulas.SUMPRODUCT
author
Ben Vogt <[email protected]>
date
2017-02-18 21:16:09
stats
4 file(s) changed,
93 insertions(+),
3 deletions(-)
files
src/RawFormulas/RawFormulas.ts
src/RawFormulas/Utils.ts
tests/FormulasTest.ts
tests/SheetFormulaTest.ts
1diff --git a/src/RawFormulas/RawFormulas.ts b/src/RawFormulas/RawFormulas.ts
2index d17701a..1e075cb 100644
3--- a/src/RawFormulas/RawFormulas.ts
4+++ b/src/RawFormulas/RawFormulas.ts
5@@ -128,11 +128,49 @@ var __COMPLEX = {
6 "F.DIST": Formula["FDIST"],
7 "F.INV": Formula["FINV"]
8 };
9-var SUMPRODUCT = Formula["SUMPRODUCT"];
10 var SUMX2MY2 = Formula["SUMX2MY2"];
11 var SUMX2PY2 = Formula["SUMX2PY2"];
12 var YEARFRAC = Formula["YEARFRAC"];
13
14+/**
15+ * Calculates the sum of the products of corresponding entries in two equal-sized arrays or ranges.
16+ * @param values Arrays or ranges whose entries will be multiplied with corresponding entries in the second such array
17+ * or range.
18+ * @returns {number} sum of the products
19+ * @constructor
20+ */
21+var SUMPRODUCT = function (...values) : number {
22+ ArgsChecker.checkAtLeastLength(values, 1);
23+ // Ensuring that all values are array values
24+ for (var x = 0; x < values.length; x++) {
25+ if (!Array.isArray(values[x])) {
26+ values[x] = [values[x]];
27+ }
28+ }
29+
30+ // Flatten any nested ranges (arrays) and check for mismatched range sizes
31+ var flattenedValues = [Filter.flattenAndThrow(values[0])];
32+ for (var x = 1; x < values.length; x++) {
33+ flattenedValues.push(Filter.flattenAndThrow(values[x]));
34+ if (flattenedValues[x].length !== flattenedValues[0].length) {
35+ throw new CellError(ERRORS.VALUE_ERROR, "SUMPRODUCT has mismatched range sizes. Expected count: "
36+ + flattenedValues[0].length + ". Actual count: " + flattenedValues[0].length + ".");
37+ }
38+ }
39+
40+ // Do the actual math
41+ var result = 0;
42+ for (var i = 0; i < flattenedValues[0].length; i++) {
43+ var product = 1;
44+ for (var x = 0; x < flattenedValues.length; x++) {
45+ product *= TypeCaster.valueToNumberGracefully(flattenedValues[x][i]);
46+ }
47+ result += product;
48+ }
49+ return result;
50+};
51+
52+
53
54 /**
55 * Returns the Fisher transformation of a specified value.
56diff --git a/src/RawFormulas/Utils.ts b/src/RawFormulas/Utils.ts
57index 447d62a..a135858 100644
58--- a/src/RawFormulas/Utils.ts
59+++ b/src/RawFormulas/Utils.ts
60@@ -116,6 +116,20 @@ class TypeCaster {
61 }
62 return 0;
63 }
64+
65+ /**
66+ * Converts any value to a number, defaulting to 0 value in cases in which it cannot coerce it to a number type
67+ * @param value to conver
68+ * @returns {number} to return. Will always return a number or 0.
69+ */
70+ static valueToNumberGracefully(value: any) : number {
71+ try {
72+ return TypeCaster.valueToNumber(value);
73+ } catch (e) {
74+ return 0;
75+ }
76+ }
77+
78 /**
79 * Converts any value to a boolean or throws an error if it cannot coerce it to the boolean type.
80 * @param value to convert
81@@ -245,7 +259,7 @@ class Filter {
82 }
83
84 /**
85- * Flatten an array of arrays of ...
86+ * Flatten an array of arrays of ...etc.
87 * @param values array of values
88 * @returns {Array} flattened array
89 */
90@@ -255,6 +269,20 @@ class Filter {
91 }, []);
92 }
93
94+ /**
95+ * Flatten an array of arrays of... etc, but throw an error if any are empty references.
96+ * @param values array of values
97+ * @returns {Array} flattened array
98+ */
99+ static flattenAndThrow(values: Array<any>) : Array<any> {
100+ return values.reduce(function (flat, toFlatten) {
101+ if (Array.isArray(toFlatten) && toFlatten.length === 0) {
102+ throw new CellError(ERRORS.REF_ERROR, "Reference does not exist.");
103+ }
104+ return flat.concat(Array.isArray(toFlatten) ? Filter.flatten(toFlatten) : toFlatten);
105+ }, []);
106+ }
107+
108 /**
109 * Filter out all strings from an array.
110 * @param arr to filter
111diff --git a/tests/FormulasTest.ts b/tests/FormulasTest.ts
112index 178a5b4..8a2341a 100644
113--- a/tests/FormulasTest.ts
114+++ b/tests/FormulasTest.ts
115@@ -1534,7 +1534,28 @@ catchAndAssertEquals(function() {
116 }, ERRORS.NA_ERROR);
117
118
119+// Test SUMPRODUCT
120+assertEquals(SUMPRODUCT([1, 5, 10], [2, 2, 2]), 32);
121+assertEquals(SUMPRODUCT([1, 5, 10], [2, 2, 2], [2, 2, 2]), 64);
122+assertEquals(SUMPRODUCT([1, 5, 10], [1, 2, 2], [1, 4, 4]), 121);
123 assertEquals(SUMPRODUCT([1, 5, 10]), 16);
124+assertEquals(SUMPRODUCT([1, 5, 10, ""]), 16);
125+assertEquals(SUMPRODUCT([1, 5, 10, 200], [2, 2, 2, ""]), 32);
126+assertEquals(SUMPRODUCT([1, 5, 10, "str"]), 16);
127+assertEquals(SUMPRODUCT([10, 10, 22, "str"], [2, 2, [2, 2]]), 84);
128+assertEquals(SUMPRODUCT(1, 5, 10), 50);
129+assertEquals(SUMPRODUCT([1, 5, 10]), 16);
130+catchAndAssertEquals(function() {
131+ SUMPRODUCT([1, 5, 10], [2, 2]);
132+}, ERRORS.VALUE_ERROR);
133+catchAndAssertEquals(function() {
134+ SUMPRODUCT([1, 5, 10], [2, 2, 2, []]);
135+}, ERRORS.REF_ERROR);
136+catchAndAssertEquals(function() {
137+ SUMPRODUCT();
138+}, ERRORS.NA_ERROR);
139+
140+
141
142 // Test SUMSQ
143 assertEquals(SUMSQ([1, 5, 10], 10), 226);
144diff --git a/tests/SheetFormulaTest.ts b/tests/SheetFormulaTest.ts
145index 3a23768..b14cf85 100644
146--- a/tests/SheetFormulaTest.ts
147+++ b/tests/SheetFormulaTest.ts
148@@ -368,7 +368,7 @@ testFormula('=SUM(10, 10)', 20);
149 testFormula('=SUMIF([1, 5, 10], 5)', 5);
150
151 // Test SUMPRODUCT
152-testFormula('=SUMPRODUCT([1, 5, 10])', 16);
153+testFormula('=SUMPRODUCT([1, 5, 10], [2, 2, 2])', 32);
154
155 // Test SUMSQ
156 testFormula('=SUMSQ([1, 5, 10], 10)', 226);