Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add Dabatabase function "DAVERAGE" #9

Closed
wants to merge 6 commits into from
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
309 changes: 309 additions & 0 deletions lib/formula.js
Original file line number Diff line number Diff line change
Expand Up @@ -263,7 +263,316 @@
}
};

Formula.FINDFIELD = function(database, title) {
var index = null;
for (var i = 0; i < database.length; i++) {
if (database[i][0] === title) {
index = i;
break;
}
}

// Return error if the input field title is incorrect
if (index == null) {
return '#VALUE!';
}
return index;
};

Formula.FINDRESULTINDEX = function(database, criteria) {
var maxCriteriaLength = criteria[0].length;
for (var i = 1; i < criteria.length; i++) {
if (criteria[i].length > maxCriteriaLength) {
maxCriteriaLength = criteria[i].length;
}
}
var columnResultIndexes = [];
for (i = 1; i < maxCriteriaLength; i++) {
var rowResultIndexes = [];
for (var j = 0; j < criteria.length; j++) {
if (criteria[j].length < maxCriteriaLength) {
continue;
}
var criteriaTitle = criteria[j][0];
var criteriaIndex = Formula.FINDFIELD(database, criteriaTitle);
var criteriaValues = _.rest(database[criteriaIndex]);
var count = 0;
var singleResultIndexes = [];
for (var k = 0; k < criteriaValues.length; k++) {
if (eval(criteriaValues[k] + criteria[j][i])) {
singleResultIndexes[count++] = k;
}
}
rowResultIndexes[j] = singleResultIndexes;
}
columnResultIndexes[i - 1] = _.intersection.apply(_, rowResultIndexes);
}

var resultIndexes = _.union.apply(_, columnResultIndexes);
return resultIndexes;
};

// Database functions
Formula.DAVERAGE = function(database, field, criteria) {
// Return error if field is not a number and not a string
if (isNaN(field) && (typeof field !== "string")) {
return '#VALUE!';
}

var resultIndexes = Formula.FINDRESULTINDEX(database, criteria);
var targetFields = [];
if (typeof field === "string") {
var index = Formula.FINDFIELD(database, field);
targetFields = _.rest(database[index]);
} else {
targetFields = _.rest(database[field]);
}
var sum = 0;
for (var i = 0; i < resultIndexes.length; i++) {
sum += targetFields[resultIndexes[i]];
}
var average = Formula.IF(resultIndexes.length === 0, "#DIV/0!", sum / resultIndexes.length);
return average;
};

Formula.DCOUNT = function(database, field, criteria) {
// Return error if field is not a number and not a string
if (isNaN(field) && (typeof field !== "string")) {
return '#VALUE!';
}
var resultIndexes = Formula.FINDRESULTINDEX(database, criteria);
var targetFields = [];
if (typeof field === "string") {
var index = Formula.FINDFIELD(database, field);
targetFields = _.rest(database[index]);
} else {
targetFields = _.rest(database[field]);
}
var targetValues = [];
for (var i = 0; i < resultIndexes.length; i++) {
targetValues[i] = targetFields[resultIndexes[i]];
}
return Formula.COUNT(targetValues);
};

Formula.DCOUNTA = function(database, field, criteria) {
// Return error if field is not a number and not a string
if (isNaN(field) && (typeof field !== "string")) {
return '#VALUE!';
}
var resultIndexes = Formula.FINDRESULTINDEX(database, criteria);
var targetFields = [];
if (typeof field === "string") {
var index = Formula.FINDFIELD(database, field);
targetFields = _.rest(database[index]);
} else {
targetFields = _.rest(database[field]);
}
var targetValues = [];
for (var i = 0; i < resultIndexes.length; i++) {
targetValues[i] = targetFields[resultIndexes[i]];
}
return Formula.COUNTA(targetValues);
};

Formula.DGET = function(database, field, criteria) {
// Return error if field is not a number and not a string
if (isNaN(field) && (typeof field !== "string")) {
return '#VALUE!';
}
var resultIndexes = Formula.FINDRESULTINDEX(database, criteria);
var targetFields = [];
if (typeof field === "string") {
var index = Formula.FINDFIELD(database, field);
targetFields = _.rest(database[index]);
} else {
targetFields = _.rest(database[field]);
}
var targetValues = 0;
// Return error if no record meets the criteria
if (resultIndexes.length === 0) {
return '#VALUE!';
}
// Returns the #NUM! error value because more than one record meets the
// criteria
if (resultIndexes.length > 1) {
return '#NUM!';
}

return targetFields[resultIndexes[0]];
};

Formula.DMAX = function(database, field, criteria) {
// Return error if field is not a number and not a string
if (isNaN(field) && (typeof field !== "string")) {
return '#VALUE!';
}
var resultIndexes = Formula.FINDRESULTINDEX(database, criteria);
var targetFields = [];
if (typeof field === "string") {
var index = Formula.FINDFIELD(database, field);
targetFields = _.rest(database[index]);
} else {
targetFields = _.rest(database[field]);
}
var maxValue = targetFields[resultIndexes[0]];
for (var i = 1; i < resultIndexes.length; i++) {
if (maxValue < targetFields[resultIndexes[i]]) {
maxValue = targetFields[resultIndexes[i]];
}
}
return maxValue;
};

Formula.DMIN = function(database, field, criteria) {
// Return error if field is not a number and not a string
if (isNaN(field) && (typeof field !== "string")) {
return '#VALUE!';
}
var resultIndexes = Formula.FINDRESULTINDEX(database, criteria);
var targetFields = [];
if (typeof field === "string") {
var index = Formula.FINDFIELD(database, field);
targetFields = _.rest(database[index]);
} else {
targetFields = _.rest(database[field]);
}
var minValue = targetFields[resultIndexes[0]];
for (var i = 1; i < resultIndexes.length; i++) {
if (minValue > targetFields[resultIndexes[i]]) {
minValue = targetFields[resultIndexes[i]];
}
}
return minValue;
};

Formula.DPRODUCT = function(database, field, criteria) {
// Return error if field is not a number and not a string
if (isNaN(field) && (typeof field !== "string")) {
return '#VALUE!';
}
var resultIndexes = Formula.FINDRESULTINDEX(database, criteria);
var targetFields = [];
if (typeof field === "string") {
var index = Formula.FINDFIELD(database, field);
targetFields = _.rest(database[index]);
} else {
targetFields = _.rest(database[field]);
}
var targetValues = [];
for (var i = 0; i < resultIndexes.length; i++) {
targetValues[i] = targetFields[resultIndexes[i]];
}
targetValues = _.compact(targetValues);
var result = 1;
for (i = 0; i < targetValues.length; i++) {
result *= targetValues[i];
}
return result;
};

Formula.DSTDEV = function(database, field, criteria) {
// Return error if field is not a number and not a string
if (isNaN(field) && (typeof field !== "string")) {
return '#VALUE!';
}
var resultIndexes = Formula.FINDRESULTINDEX(database, criteria);
var targetFields = [];
if (typeof field === "string") {
var index = Formula.FINDFIELD(database, field);
targetFields = _.rest(database[index]);
} else {
targetFields = _.rest(database[field]);
}
var targetValues = [];
for (var i = 0; i < resultIndexes.length; i++) {
targetValues[i] = targetFields[resultIndexes[i]];
}
targetValues = _.compact(targetValues);
return Formula.STDEVS(targetValues);
};

Formula.DSTDEVP = function(database, field, criteria) {
// Return error if field is not a number and not a string
if (isNaN(field) && (typeof field !== "string")) {
return '#VALUE!';
}
var resultIndexes = Formula.FINDRESULTINDEX(database, criteria);
var targetFields = [];
if (typeof field === "string") {
var index = Formula.FINDFIELD(database, field);
targetFields = _.rest(database[index]);
} else {
targetFields = _.rest(database[field]);
}
var targetValues = [];
for (var i = 0; i < resultIndexes.length; i++) {
targetValues[i] = targetFields[resultIndexes[i]];
}
targetValues = _.compact(targetValues);
return Formula.STDEVP(targetValues);
};

Formula.DSUM = function(database, field, criteria) {
// Return error if field is not a number and not a string
if (isNaN(field) && (typeof field !== "string")) {
return '#VALUE!';
}
var resultIndexes = Formula.FINDRESULTINDEX(database, criteria);
var targetFields = [];
if (typeof field === "string") {
var index = Formula.FINDFIELD(database, field);
targetFields = _.rest(database[index]);
} else {
targetFields = _.rest(database[field]);
}
var targetValues = [];
for (var i = 0; i < resultIndexes.length; i++) {
targetValues[i] = targetFields[resultIndexes[i]];
}
return Formula.SUM(targetValues);
};

Formula.DVAR = function(database, field, criteria) {
// Return error if field is not a number and not a string
if (isNaN(field) && (typeof field !== "string")) {
return '#VALUE!';
}
var resultIndexes = Formula.FINDRESULTINDEX(database, criteria);
var targetFields = [];
if (typeof field === "string") {
var index = Formula.FINDFIELD(database, field);
targetFields = _.rest(database[index]);
} else {
targetFields = _.rest(database[field]);
}
var targetValues = [];
for (var i = 0; i < resultIndexes.length; i++) {
targetValues[i] = targetFields[resultIndexes[i]];
}
return Formula.VARS(targetValues);
};

Formula.DVARP = function(database, field, criteria) {
// Return error if field is not a number and not a string
if (isNaN(field) && (typeof field !== "string")) {
return '#VALUE!';
}
var resultIndexes = Formula.FINDRESULTINDEX(database, criteria);
var targetFields = [];
if (typeof field === "string") {
var index = Formula.FINDFIELD(database, field);
targetFields = _.rest(database[index]);
} else {
targetFields = _.rest(database[field]);
}
var targetValues = [];
for (var i = 0; i < resultIndexes.length; i++) {
targetValues[i] = targetFields[resultIndexes[i]];
}
return Formula.VARP(targetValues);
};

// Date functions

Formula.DATE = function (year, month, day) {
Expand Down
14 changes: 14 additions & 0 deletions public/controller.js
Original file line number Diff line number Diff line change
Expand Up @@ -51,6 +51,20 @@ function TestCases($scope) {
return (actual == expected || arraysIdentical(actual, expected) || bypass) ? 'icon-ok-sign text-success' : 'icon-warning-sign text-error';
}

// Database functions
$scope.DAVERAGE = Formula.DAVERAGE;
$scope.DCOUNT = Formula.DCOUNT;
$scope.DCOUNTA = Formula.DCOUNTA;
$scope.DGET = Formula.DGET;
$scope.DMAX = Formula.DMAX;
$scope.DMIN = Formula.DMIN;
$scope.DPRODUCT = Formula.DPRODUCT;
$scope.DSTDEV = Formula.DSTDEV;
$scope.DSTDEVP = Formula.DSTDEVP;
$scope.DSUM = Formula.DSUM;
$scope.DVAR = Formula.DVAR;
$scope.DVARP = Formula.DVARP;

// Date functions
$scope.DATE = Formula.DATE;
$scope.DATEVALUE = Formula.DATEVALUE;
Expand Down
14 changes: 14 additions & 0 deletions public/demos.js
Original file line number Diff line number Diff line change
@@ -1,4 +1,18 @@
var FORMULA_DEMOS = [
{"type": "database", "tests": [
{"function": "DAVERAGE", "call": "DAVERAGE([['Height',18,12,13,14,9,8],['Yield',14,10,9,10,8,6]], 'Yield', [['Height','>13']])", "result": 12},
{"function": "DCOUNT", "call": "DCOUNT([['Height',18,12,13,14,9,12],['Age',20,12,14,16,8,11],['Yield',14,10,9,10,8,6]], 'Yield', [['Height','>10'],['Age','>14']])", "result": 2},
{"function": "DCOUNTA", "call": "DCOUNTA([['Height',18,12,13,14,9,12],['Age',20,12,14,16,8,11],['Yield',null,10,9,10,8,6]], 'Yield', [['Height','>10'],['Age','>14']])", "result": 1},
{"function": "DGET", "call": "DGET([['Height',18,12,13,14,9,12],['Age',20,12,14,16,8,11],['Yield',14,10,9,10,8,6]], 'Yield', [['Height','>10'],['Age','>16']])", "result": 14},
{"function": "DMAX", "call": "DMAX([['Height',18,12,13,14,9,12],['Age',20,12,14,16,8,11],['Yield',14,10,9,10,8,6]], 'Yield', [['Height','>10'],['Age','>14']])", "result": 14},
{"function": "DMIN", "call": "DMIN([['Height',18,12,13,14,9,12],['Age',20,12,14,16,8,11],['Yield',14,10,9,10,8,6]], 'Yield', [['Height','>10'],['Age','>14']])", "result": 10},
{"function": "DPRODUCT", "call": "DPRODUCT([['Height',18,12,13,14,9,12],['Age',20,12,14,16,8,11],['Yield',14,10,9,10,8,6]], 'Yield', [['Height','>10'],['Age','>14']])", "result": 140},
{"function": "DSTDEV", "call": "DSTDEV([['Height',18,12,13,14,9,12],['Age',20,12,14,16,8,11],['Yield',14,10,9,10,8,6]], 'Yield', [['Height','>10']])", "result": 2.8635642126552705},
{"function": "DSTDEVP", "call": "DSTDEVP([['Height',18,12,13,14,9,12],['Age',20,12,14,16,8,11],['Yield',14,10,9,10,8,6]], 'Yield', [['Height','>10']])", "result": 2.5612496949731396},
{"function": "DSUM", "call": "DSUM([['Height',18,12,13,14,9,12],['Age',20,12,14,16,8,11],['Yield',14,10,9,10,8,6]], 'Yield', [['Height','>10'],['Age','>14']])", "result": 24},
{"function": "DVAR", "call": "DVAR([['Height',18,12,13,14,9,12],['Age',20,12,14,16,8,11],['Yield',14,10,9,10,8,6]], 'Yield', [['Height','>10'],['Age','>14']])", "result": 8},
{"function": "DVARP", "call": "DVARP([['Height',18,12,13,14,9,12],['Age',20,12,14,16,8,11],['Yield',14,10,9,10,8,6]], 'Yield', [['Height','>10'],['Age','>14']])", "result": 4}
]},
{"type": "date", "tests": [
{"function": "DATE", "call": "DATE(2008, 7, 8)", "result": "Tue Jul 08 2008 00:00:00 GMT-0700 (PDT)"},
{"function": "DATEVALUE", "call": "DATEVALUE('8/22/2011')", "result": "Mon Aug 22 2011 00:00:00 GMT-0700 (PDT)"},
Expand Down
2 changes: 1 addition & 1 deletion public/index.html
Original file line number Diff line number Diff line change
Expand Up @@ -87,7 +87,7 @@ <h2>Function types</h2>
</thead>
<tbody>
<tr><td>Compatibility functions</td><td>Planned</td><td><a href="http://office.microsoft.com/en-us/excel-help/excel-functions-by-category-HA102752955.aspx#_Toc309306706">Excel</a></td></tr>
<tr><td>Database functions</td><td>Planned</td><td><a href="http://office.microsoft.com/en-us/excel-help/excel-functions-by-category-HA102752955.aspx#_Toc309306708">Excel</a></td></tr>
<tr><td><a href="#database">Database functions</a></td><td>Started</td><td><a href="http://office.microsoft.com/en-us/excel-help/excel-functions-by-category-HA102752955.aspx#_Toc309306708">Excel</a></td></tr>
<tr><td><a href="#date">Date and time functions</a></td><td>Implemented</td><td><a href="http://office.microsoft.com/en-us/excel-help/excel-functions-by-category-HA102752955.aspx#_Toc309306709">Excel</a></td></tr>
<tr><td><a href="#engineering">Engineering functions</a></td><td>Implemented</td><td><a href="http://office.microsoft.com/en-us/excel-help/excel-functions-by-category-HA102752955.aspx#_Toc309306710">Excel</a></td></tr>
<tr><td><a href="#financial">Financial functions</a></td><td>Started</td><td><a href="http://office.microsoft.com/en-us/excel-help/excel-functions-by-category-HA102752955.aspx#_Toc309306711">Excel</a></td></tr>
Expand Down
Loading