diff --git a/calc.go b/calc.go index e59d344..1fdaf6e 100644 --- a/calc.go +++ b/calc.go @@ -53,9 +53,8 @@ const ( criteriaGe criteriaL criteriaG - criteriaBeg - criteriaEnd criteriaErr + criteriaRegexp // Numeric precision correct numeric values as legacy Excel application // https://en.wikipedia.org/wiki/Numeric_precision_in_Microsoft_Excel In the // top figure the fraction 1/9000 in Excel is displayed. Although this number @@ -411,6 +410,7 @@ type formulaFuncs struct { // LOG10 // LOOKUP // LOWER +// MATCH // MAX // MDETERM // MEDIAN @@ -504,6 +504,7 @@ type formulaFuncs struct { // VAR.P // VARP // VLOOKUP +// XOR // YEAR // func (f *File) CalcCellValue(sheet, cell string) (result string, err error) { @@ -1285,16 +1286,13 @@ func formulaCriteriaParser(exp string) (fc *formulaCriteria) { fc.Type, fc.Condition = criteriaG, match[1] return } - if strings.Contains(exp, "*") { - if strings.HasPrefix(exp, "*") { - fc.Type, fc.Condition = criteriaEnd, strings.TrimPrefix(exp, "*") - } - if strings.HasSuffix(exp, "*") { - fc.Type, fc.Condition = criteriaBeg, strings.TrimSuffix(exp, "*") - } - return + if strings.Contains(exp, "?") { + exp = strings.ReplaceAll(exp, "?", ".") } - fc.Type, fc.Condition = criteriaEq, exp + if strings.Contains(exp, "*") { + exp = strings.ReplaceAll(exp, "*", ".*") + } + fc.Type, fc.Condition = criteriaRegexp, exp return } @@ -1326,10 +1324,8 @@ func formulaCriteriaEval(val string, criteria *formulaCriteria) (result bool, er case criteriaG: value, expected, e = prepareValue(val, criteria.Condition) return value > expected && e == nil, err - case criteriaBeg: - return strings.HasPrefix(val, criteria.Condition), err - case criteriaEnd: - return strings.HasSuffix(val, criteria.Condition), err + case criteriaRegexp: + return regexp.MatchString(criteria.Condition, val) } return } @@ -6061,6 +6057,65 @@ func (fn *formulaFuncs) TRUE(argsList *list.List) formulaArg { return newBoolFormulaArg(true) } +// calcXor checking if numeric cell exists and count it by given arguments +// sequence for the formula function XOR. +func calcXor(argsList *list.List) formulaArg { + count, ok := 0, false + for arg := argsList.Front(); arg != nil; arg = arg.Next() { + token := arg.Value.(formulaArg) + switch token.Type { + case ArgError: + return token + case ArgString: + if b := token.ToBool(); b.Type == ArgNumber { + ok = true + if b.Number == 1 { + count++ + } + continue + } + if num := token.ToNumber(); num.Type == ArgNumber { + ok = true + if num.Number != 0 { + count++ + } + } + case ArgNumber: + ok = true + if token.Number != 0 { + count++ + } + case ArgMatrix: + for _, value := range token.ToList() { + if num := value.ToNumber(); num.Type == ArgNumber { + ok = true + if num.Number != 0 { + count++ + } + } + } + } + } + if !ok { + return newErrorFormulaArg(formulaErrorVALUE, formulaErrorVALUE) + } + return newBoolFormulaArg(count%2 != 0) +} + +// XOR function returns the Exclusive Or logical operation for one or more +// supplied conditions. I.e. the Xor function returns TRUE if an odd number +// of the supplied conditions evaluate to TRUE, and FALSE otherwise. The +// syntax of the function is: +// +// XOR(logical_test1,[logical_test2],...) +// +func (fn *formulaFuncs) XOR(argsList *list.List) formulaArg { + if argsList.Len() < 1 { + return newErrorFormulaArg(formulaErrorVALUE, "XOR requires at least 1 argument") + } + return calcXor(argsList) +} + // Date and Time Functions // DATE returns a date, from a user-supplied year, month and day. The syntax @@ -7411,6 +7466,46 @@ func (fn *formulaFuncs) COLUMNS(argsList *list.List) formulaArg { return newNumberFormulaArg(float64(result)) } +// checkHVLookupArgs checking arguments, prepare extract mode, lookup value, +// and data for the formula functions HLOOKUP and VLOOKUP. +func checkHVLookupArgs(name string, argsList *list.List) (idx, matchIdx int, wasExact, exactMatch bool, lookupValue, tableArray, errArg formulaArg) { + unit := map[string]string{ + "HLOOKUP": "row", + "VLOOKUP": "col", + }[name] + if argsList.Len() < 3 { + errArg = newErrorFormulaArg(formulaErrorVALUE, fmt.Sprintf("%s requires at least 3 arguments", name)) + return + } + if argsList.Len() > 4 { + errArg = newErrorFormulaArg(formulaErrorVALUE, fmt.Sprintf("%s requires at most 4 arguments", name)) + return + } + lookupValue = argsList.Front().Value.(formulaArg) + tableArray = argsList.Front().Next().Value.(formulaArg) + if tableArray.Type != ArgMatrix { + errArg = newErrorFormulaArg(formulaErrorVALUE, fmt.Sprintf("%s requires second argument of table array", name)) + return + } + arg := argsList.Front().Next().Next().Value.(formulaArg).ToNumber() + if arg.Type != ArgNumber { + errArg = newErrorFormulaArg(formulaErrorVALUE, fmt.Sprintf("%s requires numeric %s argument", name, unit)) + return + } + idx, matchIdx = int(arg.Number)-1, -1 + if argsList.Len() == 4 { + rangeLookup := argsList.Back().Value.(formulaArg).ToBool() + if rangeLookup.Type == ArgError { + errArg = newErrorFormulaArg(formulaErrorVALUE, rangeLookup.Error) + return + } + if rangeLookup.Number == 0 { + exactMatch = true + } + } + return +} + // HLOOKUP function 'looks up' a given value in the top row of a data array // (or table), and returns the corresponding value from another row of the // array. The syntax of the function is: @@ -7418,30 +7513,10 @@ func (fn *formulaFuncs) COLUMNS(argsList *list.List) formulaArg { // HLOOKUP(lookup_value,table_array,row_index_num,[range_lookup]) // func (fn *formulaFuncs) HLOOKUP(argsList *list.List) formulaArg { - if argsList.Len() < 3 { - return newErrorFormulaArg(formulaErrorVALUE, "HLOOKUP requires at least 3 arguments") - } - if argsList.Len() > 4 { - return newErrorFormulaArg(formulaErrorVALUE, "HLOOKUP requires at most 4 arguments") - } - lookupValue := argsList.Front().Value.(formulaArg) - tableArray := argsList.Front().Next().Value.(formulaArg) - if tableArray.Type != ArgMatrix { - return newErrorFormulaArg(formulaErrorVALUE, "HLOOKUP requires second argument of table array") - } - rowArg := argsList.Front().Next().Next().Value.(formulaArg).ToNumber() - if rowArg.Type != ArgNumber { - return newErrorFormulaArg(formulaErrorVALUE, "HLOOKUP requires numeric row argument") - } - rowIdx, matchIdx, wasExact, exactMatch := int(rowArg.Number)-1, -1, false, false - if argsList.Len() == 4 { - rangeLookup := argsList.Back().Value.(formulaArg).ToBool() - if rangeLookup.Type == ArgError { - return newErrorFormulaArg(formulaErrorVALUE, rangeLookup.Error) - } - if rangeLookup.Number == 0 { - exactMatch = true - } + rowIdx, matchIdx, wasExact, exactMatch, + lookupValue, tableArray, errArg := checkHVLookupArgs("HLOOKUP", argsList) + if errArg.Type == ArgError { + return errArg } row := tableArray.Matrix[0] if exactMatch || len(tableArray.Matrix) == TotalRows { @@ -7481,6 +7556,87 @@ func (fn *formulaFuncs) HLOOKUP(argsList *list.List) formulaArg { return newErrorFormulaArg(formulaErrorNA, "HLOOKUP no result found") } +// calcMatch returns the position of the value by given match type, criteria +// and lookup array for the formula function MATCH. +func calcMatch(matchType int, criteria *formulaCriteria, lookupArray []formulaArg) formulaArg { + switch matchType { + case 0: + for i, arg := range lookupArray { + if ok, _ := formulaCriteriaEval(arg.Value(), criteria); ok { + return newNumberFormulaArg(float64(i + 1)) + } + } + case -1: + for i, arg := range lookupArray { + if ok, _ := formulaCriteriaEval(arg.Value(), criteria); ok { + return newNumberFormulaArg(float64(i + 1)) + } + if ok, _ := formulaCriteriaEval(arg.Value(), &formulaCriteria{ + Type: criteriaL, Condition: criteria.Condition, + }); ok { + if i == 0 { + return newErrorFormulaArg(formulaErrorNA, formulaErrorNA) + } + return newNumberFormulaArg(float64(i)) + } + } + case 1: + for i, arg := range lookupArray { + if ok, _ := formulaCriteriaEval(arg.Value(), criteria); ok { + return newNumberFormulaArg(float64(i + 1)) + } + if ok, _ := formulaCriteriaEval(arg.Value(), &formulaCriteria{ + Type: criteriaG, Condition: criteria.Condition, + }); ok { + if i == 0 { + return newErrorFormulaArg(formulaErrorNA, formulaErrorNA) + } + return newNumberFormulaArg(float64(i)) + } + } + } + return newErrorFormulaArg(formulaErrorNA, formulaErrorNA) +} + +// MATCH function looks up a value in an array, and returns the position of +// the value within the array. The user can specify that the function should +// only return a result if an exact match is found, or that the function +// should return the position of the closest match (above or below), if an +// exact match is not found. The syntax of the Match function is: +// +// MATCH(lookup_value,lookup_array,[match_type]) +// +func (fn *formulaFuncs) MATCH(argsList *list.List) formulaArg { + if argsList.Len() != 2 && argsList.Len() != 3 { + return newErrorFormulaArg(formulaErrorVALUE, "MATCH requires 1 or 2 arguments") + } + var ( + matchType = 1 + lookupArray []formulaArg + lookupArrayArg = argsList.Front().Next().Value.(formulaArg) + lookupArrayErr = "MATCH arguments lookup_array should be one-dimensional array" + ) + if argsList.Len() == 3 { + matchTypeArg := argsList.Back().Value.(formulaArg).ToNumber() + if matchTypeArg.Type != ArgNumber { + return newErrorFormulaArg(formulaErrorVALUE, "MATCH requires numeric match_type argument") + } + if matchTypeArg.Number == -1 || matchTypeArg.Number == 0 { + matchType = int(matchTypeArg.Number) + } + } + switch lookupArrayArg.Type { + case ArgMatrix: + if len(lookupArrayArg.Matrix[0]) != 1 { + return newErrorFormulaArg(formulaErrorNA, lookupArrayErr) + } + lookupArray = lookupArrayArg.ToList() + default: + return newErrorFormulaArg(formulaErrorNA, lookupArrayErr) + } + return calcMatch(matchType, formulaCriteriaParser(argsList.Front().Value.(formulaArg).String), lookupArray) +} + // VLOOKUP function 'looks up' a given value in the left-hand column of a // data array (or table), and returns the corresponding value from another // column of the array. The syntax of the function is: @@ -7488,30 +7644,10 @@ func (fn *formulaFuncs) HLOOKUP(argsList *list.List) formulaArg { // VLOOKUP(lookup_value,table_array,col_index_num,[range_lookup]) // func (fn *formulaFuncs) VLOOKUP(argsList *list.List) formulaArg { - if argsList.Len() < 3 { - return newErrorFormulaArg(formulaErrorVALUE, "VLOOKUP requires at least 3 arguments") - } - if argsList.Len() > 4 { - return newErrorFormulaArg(formulaErrorVALUE, "VLOOKUP requires at most 4 arguments") - } - lookupValue := argsList.Front().Value.(formulaArg) - tableArray := argsList.Front().Next().Value.(formulaArg) - if tableArray.Type != ArgMatrix { - return newErrorFormulaArg(formulaErrorVALUE, "VLOOKUP requires second argument of table array") - } - colIdx := argsList.Front().Next().Next().Value.(formulaArg).ToNumber() - if colIdx.Type != ArgNumber { - return newErrorFormulaArg(formulaErrorVALUE, "VLOOKUP requires numeric col argument") - } - col, matchIdx, wasExact, exactMatch := int(colIdx.Number)-1, -1, false, false - if argsList.Len() == 4 { - rangeLookup := argsList.Back().Value.(formulaArg).ToBool() - if rangeLookup.Type == ArgError { - return newErrorFormulaArg(formulaErrorVALUE, rangeLookup.Error) - } - if rangeLookup.Number == 0 { - exactMatch = true - } + colIdx, matchIdx, wasExact, exactMatch, + lookupValue, tableArray, errArg := checkHVLookupArgs("VLOOKUP", argsList) + if errArg.Type == ArgError { + return errArg } if exactMatch || len(tableArray.Matrix) == TotalRows { start: @@ -7541,11 +7677,11 @@ func (fn *formulaFuncs) VLOOKUP(argsList *list.List) formulaArg { return newErrorFormulaArg(formulaErrorNA, "VLOOKUP no result found") } mtx := tableArray.Matrix[matchIdx] - if col < 0 || col >= len(mtx) { + if colIdx < 0 || colIdx >= len(mtx) { return newErrorFormulaArg(formulaErrorNA, "VLOOKUP has invalid column index") } if wasExact || !exactMatch { - return mtx[col] + return mtx[colIdx] } return newErrorFormulaArg(formulaErrorNA, "VLOOKUP no result found") } diff --git a/calc_test.go b/calc_test.go index e5a6e1e..d526b34 100644 --- a/calc_test.go +++ b/calc_test.go @@ -926,6 +926,10 @@ func TestCalcCellValue(t *testing.T) { "=OR(1=2,2=3)": "FALSE", // TRUE "=TRUE()": "TRUE", + // XOR + "=XOR(1>0,2>0)": "FALSE", + "=XOR(1>0,0>1)": "TRUE", + "=XOR(1>0,0>1,INT(0),INT(1),A1:A4,2)": "FALSE", // Date and Time Functions // DATE "=DATE(2020,10,21)": "2020-10-21 00:00:00 +0000 UTC", @@ -1946,6 +1950,10 @@ func TestCalcCellValue(t *testing.T) { "=OR(1" + strings.Repeat(",1", 30) + ")": "OR accepts at most 30 arguments", // TRUE "=TRUE(A1)": "TRUE takes no arguments", + // XOR + "=XOR()": "XOR requires at least 1 argument", + "=XOR(\"text\")": "#VALUE!", + "=XOR(XOR(\"text\"))": "#VALUE!", // Date and Time Functions // DATE "=DATE()": "DATE requires 3 number arguments", @@ -2152,6 +2160,12 @@ func TestCalcCellValue(t *testing.T) { "=HLOOKUP(INT(1),E2:E9,1)": "HLOOKUP no result found", "=HLOOKUP(MUNIT(2),MUNIT(3),1)": "HLOOKUP no result found", "=HLOOKUP(A1:B2,B2:B3,1)": "HLOOKUP no result found", + // MATCH + "=MATCH()": "MATCH requires 1 or 2 arguments", + "=MATCH(0,A1:A1,0,0)": "MATCH requires 1 or 2 arguments", + "=MATCH(0,A1:A1,\"x\")": "MATCH requires numeric match_type argument", + "=MATCH(0,A1)": "MATCH arguments lookup_array should be one-dimensional array", + "=MATCH(0,A1:B1)": "MATCH arguments lookup_array should be one-dimensional array", // VLOOKUP "=VLOOKUP()": "VLOOKUP requires at least 3 arguments", "=VLOOKUP(D2,D1,1,FALSE)": "VLOOKUP requires second argument of table array", @@ -2691,6 +2705,48 @@ func TestCalcMIRR(t *testing.T) { } } +func TestCalcMATCH(t *testing.T) { + f := NewFile() + for cell, row := range map[string][]interface{}{ + "A1": {"cccc", 7, 4, 16}, + "A2": {"dddd", 2, 6, 11}, + "A3": {"aaaa", 4, 7, 10}, + "A4": {"bbbb", 1, 10, 7}, + "A5": {"eeee", 8, 11, 6}, + "A6": {nil, 11, 16, 4}, + } { + assert.NoError(t, f.SetSheetRow("Sheet1", cell, &row)) + } + formulaList := map[string]string{ + "=MATCH(\"aaaa\",A1:A6,0)": "3", + "=MATCH(\"*b\",A1:A5,0)": "4", + "=MATCH(\"?eee\",A1:A5,0)": "5", + "=MATCH(\"?*?e\",A1:A5,0)": "5", + "=MATCH(\"aaaa\",A1:A6,1)": "3", + "=MATCH(10,B1:B6)": "5", + "=MATCH(8,C1:C6,1)": "3", + "=MATCH(6,B1:B6,-1)": "1", + "=MATCH(10,D1:D6,-1)": "3", + } + for formula, expected := range formulaList { + assert.NoError(t, f.SetCellFormula("Sheet1", "E1", formula)) + result, err := f.CalcCellValue("Sheet1", "E1") + assert.NoError(t, err, formula) + assert.Equal(t, expected, result, formula) + } + calcError := map[string]string{ + "=MATCH(3,C1:C6,1)": "#N/A", + "=MATCH(5,C1:C6,-1)": "#N/A", + } + for formula, expected := range calcError { + assert.NoError(t, f.SetCellFormula("Sheet1", "E1", formula)) + result, err := f.CalcCellValue("Sheet1", "E1") + assert.EqualError(t, err, expected, formula) + assert.Equal(t, "", result, formula) + } + assert.Equal(t, newErrorFormulaArg(formulaErrorNA, formulaErrorNA), calcMatch(2, nil, []formulaArg{})) +} + func TestStrToDate(t *testing.T) { _, _, _, _, err := strToDate("") assert.Equal(t, formulaErrorVALUE, err.Error)