ref #65, new formula functions MAXIFS and MINIFS
This commit is contained in:
parent
63fe422299
commit
6051434bf8
119
calc.go
119
calc.go
|
@ -479,6 +479,8 @@ type formulaFuncs struct {
|
||||||
// LOWER
|
// LOWER
|
||||||
// MATCH
|
// MATCH
|
||||||
// MAX
|
// MAX
|
||||||
|
// MAXA
|
||||||
|
// MAXIFS
|
||||||
// MDETERM
|
// MDETERM
|
||||||
// MDURATION
|
// MDURATION
|
||||||
// MEDIAN
|
// MEDIAN
|
||||||
|
@ -486,6 +488,7 @@ type formulaFuncs struct {
|
||||||
// MIDB
|
// MIDB
|
||||||
// MIN
|
// MIN
|
||||||
// MINA
|
// MINA
|
||||||
|
// MINIFS
|
||||||
// MINUTE
|
// MINUTE
|
||||||
// MIRR
|
// MIRR
|
||||||
// MOD
|
// MOD
|
||||||
|
@ -5224,6 +5227,35 @@ func (fn *formulaFuncs) COUNTIF(argsList *list.List) formulaArg {
|
||||||
return newNumberFormulaArg(count)
|
return newNumberFormulaArg(count)
|
||||||
}
|
}
|
||||||
|
|
||||||
|
// formulaIfsMatch function returns cells reference array which match criterias.
|
||||||
|
func formulaIfsMatch(args []formulaArg) (cellRefs []cellRef) {
|
||||||
|
for i := 0; i < len(args)-1; i += 2 {
|
||||||
|
match := []cellRef{}
|
||||||
|
matrix, criteria := args[i].Matrix, formulaCriteriaParser(args[i+1].Value())
|
||||||
|
if i == 0 {
|
||||||
|
for rowIdx, row := range matrix {
|
||||||
|
for colIdx, col := range row {
|
||||||
|
if ok, _ := formulaCriteriaEval(col.Value(), criteria); ok {
|
||||||
|
match = append(match, cellRef{Col: colIdx, Row: rowIdx})
|
||||||
|
}
|
||||||
|
}
|
||||||
|
}
|
||||||
|
} else {
|
||||||
|
for _, ref := range cellRefs {
|
||||||
|
value := matrix[ref.Row][ref.Col]
|
||||||
|
if ok, _ := formulaCriteriaEval(value.Value(), criteria); ok {
|
||||||
|
match = append(match, ref)
|
||||||
|
}
|
||||||
|
}
|
||||||
|
}
|
||||||
|
if len(match) == 0 {
|
||||||
|
return
|
||||||
|
}
|
||||||
|
cellRefs = match[:]
|
||||||
|
}
|
||||||
|
return
|
||||||
|
}
|
||||||
|
|
||||||
// COUNTIFS function returns the number of rows within a table, that satisfy a
|
// COUNTIFS function returns the number of rows within a table, that satisfy a
|
||||||
// set of given criteria. The syntax of the function is:
|
// set of given criteria. The syntax of the function is:
|
||||||
//
|
//
|
||||||
|
@ -5236,34 +5268,11 @@ func (fn *formulaFuncs) COUNTIFS(argsList *list.List) formulaArg {
|
||||||
if argsList.Len()%2 != 0 {
|
if argsList.Len()%2 != 0 {
|
||||||
return newErrorFormulaArg(formulaErrorNA, formulaErrorNA)
|
return newErrorFormulaArg(formulaErrorNA, formulaErrorNA)
|
||||||
}
|
}
|
||||||
group, rowsIdx := 0, map[int]struct{}{}
|
args := []formulaArg{}
|
||||||
for criteriaRange := argsList.Front(); criteriaRange != nil; criteriaRange = criteriaRange.Next() {
|
for arg := argsList.Front(); arg != nil; arg = arg.Next() {
|
||||||
criteria := criteriaRange.Next()
|
args = append(args, arg.Value.(formulaArg))
|
||||||
if group == 0 {
|
|
||||||
for rowIdx, row := range criteriaRange.Value.(formulaArg).Matrix {
|
|
||||||
for _, col := range row {
|
|
||||||
if ok, _ := formulaCriteriaEval(col.String, formulaCriteriaParser(criteria.Value.(formulaArg).Value())); ok {
|
|
||||||
rowsIdx[rowIdx] = struct{}{}
|
|
||||||
}
|
|
||||||
}
|
|
||||||
}
|
|
||||||
} else {
|
|
||||||
for rowIdx, row := range criteriaRange.Value.(formulaArg).Matrix {
|
|
||||||
if _, ok := rowsIdx[rowIdx]; !ok {
|
|
||||||
delete(rowsIdx, rowIdx)
|
|
||||||
continue
|
|
||||||
}
|
|
||||||
for _, col := range row {
|
|
||||||
if ok, _ := formulaCriteriaEval(col.String, formulaCriteriaParser(criteria.Value.(formulaArg).Value())); !ok {
|
|
||||||
delete(rowsIdx, rowIdx)
|
|
||||||
}
|
|
||||||
}
|
|
||||||
}
|
|
||||||
}
|
|
||||||
criteriaRange = criteriaRange.Next()
|
|
||||||
group++
|
|
||||||
}
|
}
|
||||||
return newNumberFormulaArg(float64(len(rowsIdx)))
|
return newNumberFormulaArg(float64(len(formulaIfsMatch(args))))
|
||||||
}
|
}
|
||||||
|
|
||||||
// DEVSQ function calculates the sum of the squared deviations from the sample
|
// DEVSQ function calculates the sum of the squared deviations from the sample
|
||||||
|
@ -5765,6 +5774,34 @@ func (fn *formulaFuncs) MAXA(argsList *list.List) formulaArg {
|
||||||
return fn.max(true, argsList)
|
return fn.max(true, argsList)
|
||||||
}
|
}
|
||||||
|
|
||||||
|
// MAXIFS function returns the maximum value from a subset of values that are
|
||||||
|
// specified according to one or more criteria. The syntax of the function
|
||||||
|
// is:
|
||||||
|
//
|
||||||
|
// MAXIFS(max_range,criteria_range1,criteria1,[criteria_range2,criteria2],...)
|
||||||
|
//
|
||||||
|
func (fn *formulaFuncs) MAXIFS(argsList *list.List) formulaArg {
|
||||||
|
if argsList.Len() < 3 {
|
||||||
|
return newErrorFormulaArg(formulaErrorVALUE, "MAXIFS requires at least 3 arguments")
|
||||||
|
}
|
||||||
|
if argsList.Len()%2 != 1 {
|
||||||
|
return newErrorFormulaArg(formulaErrorNA, formulaErrorNA)
|
||||||
|
}
|
||||||
|
max, maxRange, args := -math.MaxFloat64, argsList.Front().Value.(formulaArg).Matrix, []formulaArg{}
|
||||||
|
for arg := argsList.Front().Next(); arg != nil; arg = arg.Next() {
|
||||||
|
args = append(args, arg.Value.(formulaArg))
|
||||||
|
}
|
||||||
|
for _, ref := range formulaIfsMatch(args) {
|
||||||
|
if num := maxRange[ref.Row][ref.Col].ToNumber(); num.Type == ArgNumber && max < num.Number {
|
||||||
|
max = num.Number
|
||||||
|
}
|
||||||
|
}
|
||||||
|
if max == -math.MaxFloat64 {
|
||||||
|
max = 0
|
||||||
|
}
|
||||||
|
return newNumberFormulaArg(max)
|
||||||
|
}
|
||||||
|
|
||||||
// calcListMatrixMax is part of the implementation max.
|
// calcListMatrixMax is part of the implementation max.
|
||||||
func calcListMatrixMax(maxa bool, max float64, arg formulaArg) float64 {
|
func calcListMatrixMax(maxa bool, max float64, arg formulaArg) float64 {
|
||||||
for _, row := range arg.ToList() {
|
for _, row := range arg.ToList() {
|
||||||
|
@ -5900,6 +5937,34 @@ func (fn *formulaFuncs) MINA(argsList *list.List) formulaArg {
|
||||||
return fn.min(true, argsList)
|
return fn.min(true, argsList)
|
||||||
}
|
}
|
||||||
|
|
||||||
|
// MINIFS function returns the minimum value from a subset of values that are
|
||||||
|
// specified according to one or more criteria. The syntax of the function
|
||||||
|
// is:
|
||||||
|
//
|
||||||
|
// MINIFS(min_range,criteria_range1,criteria1,[criteria_range2,criteria2],...)
|
||||||
|
//
|
||||||
|
func (fn *formulaFuncs) MINIFS(argsList *list.List) formulaArg {
|
||||||
|
if argsList.Len() < 3 {
|
||||||
|
return newErrorFormulaArg(formulaErrorVALUE, "MINIFS requires at least 3 arguments")
|
||||||
|
}
|
||||||
|
if argsList.Len()%2 != 1 {
|
||||||
|
return newErrorFormulaArg(formulaErrorNA, formulaErrorNA)
|
||||||
|
}
|
||||||
|
min, minRange, args := math.MaxFloat64, argsList.Front().Value.(formulaArg).Matrix, []formulaArg{}
|
||||||
|
for arg := argsList.Front().Next(); arg != nil; arg = arg.Next() {
|
||||||
|
args = append(args, arg.Value.(formulaArg))
|
||||||
|
}
|
||||||
|
for _, ref := range formulaIfsMatch(args) {
|
||||||
|
if num := minRange[ref.Row][ref.Col].ToNumber(); num.Type == ArgNumber && min > num.Number {
|
||||||
|
min = num.Number
|
||||||
|
}
|
||||||
|
}
|
||||||
|
if min == math.MaxFloat64 {
|
||||||
|
min = 0
|
||||||
|
}
|
||||||
|
return newNumberFormulaArg(min)
|
||||||
|
}
|
||||||
|
|
||||||
// calcListMatrixMin is part of the implementation min.
|
// calcListMatrixMin is part of the implementation min.
|
||||||
func calcListMatrixMin(mina bool, min float64, arg formulaArg) float64 {
|
func calcListMatrixMin(mina bool, min float64, arg formulaArg) float64 {
|
||||||
for _, row := range arg.ToList() {
|
for _, row := range arg.ToList() {
|
||||||
|
|
36
calc_test.go
36
calc_test.go
|
@ -2,6 +2,7 @@ package excelize
|
||||||
|
|
||||||
import (
|
import (
|
||||||
"container/list"
|
"container/list"
|
||||||
|
"math"
|
||||||
"path/filepath"
|
"path/filepath"
|
||||||
"strings"
|
"strings"
|
||||||
"testing"
|
"testing"
|
||||||
|
@ -802,6 +803,7 @@ func TestCalcCellValue(t *testing.T) {
|
||||||
// COUNTIFS
|
// COUNTIFS
|
||||||
"=COUNTIFS(A1:A9,2,D1:D9,\"Jan\")": "1",
|
"=COUNTIFS(A1:A9,2,D1:D9,\"Jan\")": "1",
|
||||||
"=COUNTIFS(F1:F9,\">20000\",D1:D9,\"Jan\")": "4",
|
"=COUNTIFS(F1:F9,\">20000\",D1:D9,\"Jan\")": "4",
|
||||||
|
"=COUNTIFS(F1:F9,\">60000\",D1:D9,\"Jan\")": "0",
|
||||||
// DEVSQ
|
// DEVSQ
|
||||||
"=DEVSQ(1,3,5,2,9,7)": "47.5",
|
"=DEVSQ(1,3,5,2,9,7)": "47.5",
|
||||||
"=DEVSQ(A1:D2)": "10",
|
"=DEVSQ(A1:D2)": "10",
|
||||||
|
@ -872,6 +874,8 @@ func TestCalcCellValue(t *testing.T) {
|
||||||
"=MAXA(MUNIT(2))": "1",
|
"=MAXA(MUNIT(2))": "1",
|
||||||
"=MAXA(INT(1))": "1",
|
"=MAXA(INT(1))": "1",
|
||||||
"=MAXA(A1:B4,MUNIT(1),INT(0),1,E1:F2,\"\")": "36693",
|
"=MAXA(A1:B4,MUNIT(1),INT(0),1,E1:F2,\"\")": "36693",
|
||||||
|
// MAXIFS
|
||||||
|
"=MAXIFS(F2:F4,A2:A4,\">0\")": "36693",
|
||||||
// MEDIAN
|
// MEDIAN
|
||||||
"=MEDIAN(A1:A5,12)": "2",
|
"=MEDIAN(A1:A5,12)": "2",
|
||||||
"=MEDIAN(A1:A5)": "1.5",
|
"=MEDIAN(A1:A5)": "1.5",
|
||||||
|
@ -891,6 +895,8 @@ func TestCalcCellValue(t *testing.T) {
|
||||||
"=MINA(MUNIT(2))": "0",
|
"=MINA(MUNIT(2))": "0",
|
||||||
"=MINA(INT(1))": "1",
|
"=MINA(INT(1))": "1",
|
||||||
"=MINA(A1:B4,MUNIT(1),INT(0),1,E1:F2,\"\")": "0",
|
"=MINA(A1:B4,MUNIT(1),INT(0),1,E1:F2,\"\")": "0",
|
||||||
|
// MINIFS
|
||||||
|
"=MINIFS(F2:F4,A2:A4,\">0\")": "22100",
|
||||||
// PERCENTILE.EXC
|
// PERCENTILE.EXC
|
||||||
"=PERCENTILE.EXC(A1:A4,0.2)": "0",
|
"=PERCENTILE.EXC(A1:A4,0.2)": "0",
|
||||||
"=PERCENTILE.EXC(A1:A4,0.6)": "2",
|
"=PERCENTILE.EXC(A1:A4,0.6)": "2",
|
||||||
|
@ -2296,6 +2302,9 @@ func TestCalcCellValue(t *testing.T) {
|
||||||
// MAXA
|
// MAXA
|
||||||
"=MAXA()": "MAXA requires at least 1 argument",
|
"=MAXA()": "MAXA requires at least 1 argument",
|
||||||
"=MAXA(NA())": "#N/A",
|
"=MAXA(NA())": "#N/A",
|
||||||
|
// MAXIFS
|
||||||
|
"=MAXIFS()": "MAXIFS requires at least 3 arguments",
|
||||||
|
"=MAXIFS(F2:F4,A2:A4,\">0\",D2:D9)": "#N/A",
|
||||||
// MEDIAN
|
// MEDIAN
|
||||||
"=MEDIAN()": "MEDIAN requires at least 1 argument",
|
"=MEDIAN()": "MEDIAN requires at least 1 argument",
|
||||||
"=MEDIAN(\"\")": "strconv.ParseFloat: parsing \"\": invalid syntax",
|
"=MEDIAN(\"\")": "strconv.ParseFloat: parsing \"\": invalid syntax",
|
||||||
|
@ -2306,6 +2315,9 @@ func TestCalcCellValue(t *testing.T) {
|
||||||
// MINA
|
// MINA
|
||||||
"=MINA()": "MINA requires at least 1 argument",
|
"=MINA()": "MINA requires at least 1 argument",
|
||||||
"=MINA(NA())": "#N/A",
|
"=MINA(NA())": "#N/A",
|
||||||
|
// MINIFS
|
||||||
|
"=MINIFS()": "MINIFS requires at least 3 arguments",
|
||||||
|
"=MINIFS(F2:F4,A2:A4,\"<0\",D2:D9)": "#N/A",
|
||||||
// PERCENTILE.EXC
|
// PERCENTILE.EXC
|
||||||
"=PERCENTILE.EXC()": "PERCENTILE.EXC requires 2 arguments",
|
"=PERCENTILE.EXC()": "PERCENTILE.EXC requires 2 arguments",
|
||||||
"=PERCENTILE.EXC(A1:A4,\"\")": "strconv.ParseFloat: parsing \"\": invalid syntax",
|
"=PERCENTILE.EXC(A1:A4,\"\")": "strconv.ParseFloat: parsing \"\": invalid syntax",
|
||||||
|
@ -3679,6 +3691,30 @@ func TestCalcIRR(t *testing.T) {
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
|
func TestCalcMAXMINIFS(t *testing.T) {
|
||||||
|
f := NewFile()
|
||||||
|
for cell, row := range map[string][]interface{}{
|
||||||
|
"A1": {1, -math.MaxFloat64 - 1},
|
||||||
|
"A2": {2, -math.MaxFloat64 - 2},
|
||||||
|
"A3": {3, math.MaxFloat64 + 1},
|
||||||
|
"A4": {4, math.MaxFloat64 + 2},
|
||||||
|
} {
|
||||||
|
assert.NoError(t, f.SetSheetRow("Sheet1", cell, &row))
|
||||||
|
}
|
||||||
|
formulaList := map[string]string{
|
||||||
|
"=MAX(B1:B2)": "0",
|
||||||
|
"=MAXIFS(B1:B2,A1:A2,\">0\")": "0",
|
||||||
|
"=MIN(B3:B4)": "0",
|
||||||
|
"=MINIFS(B3:B4,A3:A4,\"<0\")": "0",
|
||||||
|
}
|
||||||
|
for formula, expected := range formulaList {
|
||||||
|
assert.NoError(t, f.SetCellFormula("Sheet1", "C1", formula))
|
||||||
|
result, err := f.CalcCellValue("Sheet1", "C1")
|
||||||
|
assert.NoError(t, err, formula)
|
||||||
|
assert.Equal(t, expected, result, formula)
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
func TestCalcMIRR(t *testing.T) {
|
func TestCalcMIRR(t *testing.T) {
|
||||||
cellData := [][]interface{}{{-100}, {18}, {22.5}, {28}, {35.5}, {45}}
|
cellData := [][]interface{}{{-100}, {18}, {22.5}, {28}, {35.5}, {45}}
|
||||||
f := prepareCalcData(cellData)
|
f := prepareCalcData(cellData)
|
||||||
|
|
Loading…
Reference in New Issue