ref #65, formula functions TEXTAFTER and TEXTBEFORE (array formula not support yet)

This commit is contained in:
xuri 2023-10-01 13:37:47 +08:00
parent 1c23dc3507
commit f85770f4c9
No known key found for this signature in database
GPG Key ID: BA5E5BB1C948EDF7
3 changed files with 231 additions and 8 deletions

172
calc.go
View File

@ -314,7 +314,7 @@ func (fa formulaArg) ToBool() formulaArg {
return newErrorFormulaArg(formulaErrorVALUE, err.Error())
}
case ArgNumber:
if fa.Boolean && fa.Number == 1 {
if fa.Number == 1 {
b = true
}
}
@ -758,6 +758,8 @@ type formulaFuncs struct {
// TBILLYIELD
// TDIST
// TEXT
// TEXTAFTER
// TEXTBEFORE
// TEXTJOIN
// TIME
// TIMEVALUE
@ -13748,7 +13750,7 @@ func (fn *formulaFuncs) LEN(argsList *list.List) formulaArg {
if argsList.Len() != 1 {
return newErrorFormulaArg(formulaErrorVALUE, "LEN requires 1 string argument")
}
return newStringFormulaArg(strconv.Itoa(utf8.RuneCountInString(argsList.Front().Value.(formulaArg).String)))
return newNumberFormulaArg(float64(utf8.RuneCountInString(argsList.Front().Value.(formulaArg).String)))
}
// LENB returns the number of bytes used to represent the characters in a text
@ -13770,7 +13772,7 @@ func (fn *formulaFuncs) LENB(argsList *list.List) formulaArg {
bytes += 2
}
}
return newStringFormulaArg(strconv.Itoa(bytes))
return newNumberFormulaArg(float64(bytes))
}
// LOWER converts all characters in a supplied text string to lower case. The
@ -14058,6 +14060,163 @@ func (fn *formulaFuncs) TEXT(argsList *list.List) formulaArg {
return newStringFormulaArg(format(value.Value(), fmtText.Value(), false, cellType, nil))
}
// prepareTextAfterBefore checking and prepare arguments for the formula
// functions TEXTAFTER and TEXTBEFORE.
func (fn *formulaFuncs) prepareTextAfterBefore(name string, argsList *list.List) formulaArg {
argsLen := argsList.Len()
if argsLen < 2 {
return newErrorFormulaArg(formulaErrorVALUE, fmt.Sprintf("%s requires at least 2 arguments", name))
}
if argsLen > 6 {
return newErrorFormulaArg(formulaErrorVALUE, fmt.Sprintf("%s accepts at most 6 arguments", name))
}
text, delimiter := argsList.Front().Value.(formulaArg), argsList.Front().Next().Value.(formulaArg)
instanceNum, matchMode, matchEnd, ifNotFound := newNumberFormulaArg(1), newBoolFormulaArg(false), newBoolFormulaArg(false), newEmptyFormulaArg()
if argsLen > 2 {
instanceNum = argsList.Front().Next().Next().Value.(formulaArg).ToNumber()
if instanceNum.Type != ArgNumber {
return instanceNum
}
}
if argsLen > 3 {
matchMode = argsList.Front().Next().Next().Next().Value.(formulaArg).ToBool()
if matchMode.Type != ArgNumber {
return matchMode
}
if matchMode.Number == 1 {
text, delimiter = newStringFormulaArg(strings.ToLower(text.Value())), newStringFormulaArg(strings.ToLower(delimiter.Value()))
}
}
if argsLen > 4 {
matchEnd = argsList.Front().Next().Next().Next().Next().Value.(formulaArg).ToBool()
if matchEnd.Type != ArgNumber {
return matchEnd
}
}
if argsLen > 5 {
ifNotFound = argsList.Back().Value.(formulaArg)
}
if text.Value() == "" {
return newErrorFormulaArg(formulaErrorNA, formulaErrorNA)
}
lenArgsList := list.New().Init()
lenArgsList.PushBack(text)
textLen := fn.LEN(lenArgsList)
if instanceNum.Number == 0 || instanceNum.Number > textLen.Number {
return newErrorFormulaArg(formulaErrorVALUE, formulaErrorVALUE)
}
reverseSearch, startPos := instanceNum.Number < 0, 0.0
if reverseSearch {
startPos = textLen.Number
}
return newListFormulaArg([]formulaArg{
text, delimiter, instanceNum, matchMode, matchEnd, ifNotFound,
textLen, newBoolFormulaArg(reverseSearch), newNumberFormulaArg(startPos),
})
}
// textAfterBeforeSearch is an implementation of the formula functions TEXTAFTER
// and TEXTBEFORE.
func textAfterBeforeSearch(text string, delimiter []string, startPos int, reverseSearch bool) (int, string) {
idx := -1
var modifiedDelimiter string
for i := 0; i < len(delimiter); i++ {
nextDelimiter := delimiter[i]
nextIdx := strings.Index(text[startPos:], nextDelimiter)
if nextIdx != -1 {
nextIdx += startPos
}
if reverseSearch {
nextIdx = strings.LastIndex(text[:startPos], nextDelimiter)
}
if idx == -1 || (((nextIdx < idx && !reverseSearch) || (nextIdx > idx && reverseSearch)) && idx != -1) {
idx = nextIdx
modifiedDelimiter = nextDelimiter
}
}
return idx, modifiedDelimiter
}
// textAfterBeforeResult is an implementation of the formula functions TEXTAFTER
// and TEXTBEFORE.
func textAfterBeforeResult(name, modifiedDelimiter string, text []rune, foundIdx, repeatZero, textLen int, matchEndActive, matchEnd, reverseSearch bool) formulaArg {
if name == "TEXTAFTER" {
endPos := len(modifiedDelimiter)
if (repeatZero > 1 || matchEndActive) && matchEnd && reverseSearch {
endPos = 0
}
if foundIdx+endPos >= textLen {
return newEmptyFormulaArg()
}
return newStringFormulaArg(string(text[foundIdx+endPos : textLen]))
}
return newStringFormulaArg(string(text[:foundIdx]))
}
// textAfterBefore is an implementation of the formula functions TEXTAFTER and
// TEXTBEFORE.
func (fn *formulaFuncs) textAfterBefore(name string, argsList *list.List) formulaArg {
args := fn.prepareTextAfterBefore(name, argsList)
if args.Type != ArgList {
return args
}
var (
text = []rune(argsList.Front().Value.(formulaArg).Value())
modifiedText = args.List[0].Value()
delimiter = []string{args.List[1].Value()}
instanceNum = args.List[2].Number
matchEnd = args.List[4].Number == 1
ifNotFound = args.List[5]
textLen = args.List[6]
reverseSearch = args.List[7].Number == 1
foundIdx = -1
repeatZero, startPos int
matchEndActive bool
modifiedDelimiter string
)
if reverseSearch {
startPos = int(args.List[8].Number)
}
for i := 0; i < int(math.Abs(instanceNum)); i++ {
foundIdx, modifiedDelimiter = textAfterBeforeSearch(modifiedText, delimiter, startPos, reverseSearch)
if foundIdx == 0 {
repeatZero++
}
if foundIdx == -1 {
if matchEnd && i == int(math.Abs(instanceNum))-1 {
if foundIdx = int(textLen.Number); reverseSearch {
foundIdx = 0
}
matchEndActive = true
}
break
}
if startPos = foundIdx + len(modifiedDelimiter); reverseSearch {
startPos = foundIdx - len(modifiedDelimiter)
}
}
if foundIdx == -1 {
return ifNotFound
}
return textAfterBeforeResult(name, modifiedDelimiter, text, foundIdx, repeatZero, int(textLen.Number), matchEndActive, matchEnd, reverseSearch)
}
// TEXTAFTER function returns the text that occurs after a given substring or
// delimiter. The syntax of the function is:
//
// TEXTAFTER(text,delimiter,[instance_num],[match_mode],[match_end],[if_not_found])
func (fn *formulaFuncs) TEXTAFTER(argsList *list.List) formulaArg {
return fn.textAfterBefore("TEXTAFTER", argsList)
}
// TEXTBEFORE function returns text that occurs before a given character or
// string. The syntax of the function is:
//
// TEXTBEFORE(text,delimiter,[instance_num],[match_mode],[match_end],[if_not_found])
func (fn *formulaFuncs) TEXTBEFORE(argsList *list.List) formulaArg {
return fn.textAfterBefore("TEXTBEFORE", argsList)
}
// TEXTJOIN function joins together a series of supplied text strings into one
// combined text string. The user can specify a delimiter to add between the
// individual text items, if required. The syntax of the function is:
@ -14465,8 +14624,7 @@ func compareFormulaArgMatrix(lhs, rhs, matchMode formulaArg, caseSensitive bool)
return criteriaG
}
for i := range lhs.Matrix {
left := lhs.Matrix[i]
right := lhs.Matrix[i]
left, right := lhs.Matrix[i], rhs.Matrix[i]
if len(left) < len(right) {
return criteriaL
}
@ -15289,7 +15447,7 @@ func (fn *formulaFuncs) ROWS(argsList *list.List) formulaArg {
}
min, max := calcColsRowsMinMax(false, argsList)
if max == TotalRows {
return newStringFormulaArg(strconv.Itoa(TotalRows))
return newNumberFormulaArg(TotalRows)
}
result := max - min + 1
if max == min {
@ -15298,7 +15456,7 @@ func (fn *formulaFuncs) ROWS(argsList *list.List) formulaArg {
}
return newNumberFormulaArg(float64(1))
}
return newStringFormulaArg(strconv.Itoa(result))
return newNumberFormulaArg(float64(result))
}
// Web Functions

View File

@ -1843,6 +1843,35 @@ func TestCalcCellValue(t *testing.T) {
"=TEXT(567.9,\"$#,##0.00\")": "$567.90",
"=TEXT(-5,\"+ $#,##0.00;- $#,##0.00;$0.00\")": "- $5.00",
"=TEXT(5,\"+ $#,##0.00;- $#,##0.00;$0.00\")": "+ $5.00",
// TEXTAFTER
"=TEXTAFTER(\"Red riding hood's, red hood\",\"hood\")": "'s, red hood",
"=TEXTAFTER(\"Red riding hood's, red hood\",\"HOOD\",1,1)": "'s, red hood",
"=TEXTAFTER(\"Red riding hood's, red hood\",\"basket\",1,0,0,\"x\")": "x",
"=TEXTAFTER(\"Red riding hood's, red hood\",\"basket\",1,0,1,\"x\")": "",
"=TEXTAFTER(\"Red riding hood's, red hood\",\"hood\",-1)": "",
"=TEXTAFTER(\"Jones,Bob\",\",\")": "Bob",
"=TEXTAFTER(\"12 ft x 20 ft\",\" x \")": "20 ft",
"=TEXTAFTER(\"ABX-112-Red-Y\",\"-\",1)": "112-Red-Y",
"=TEXTAFTER(\"ABX-112-Red-Y\",\"-\",2)": "Red-Y",
"=TEXTAFTER(\"ABX-112-Red-Y\",\"-\",-1)": "Y",
"=TEXTAFTER(\"ABX-112-Red-Y\",\"-\",-2)": "Red-Y",
"=TEXTAFTER(\"ABX-112-Red-Y\",\"-\",-3)": "112-Red-Y",
"=TEXTAFTER(\"ABX-123-Red-XYZ\",\"-\",-4,0,1)": "ABX-123-Red-XYZ",
"=TEXTAFTER(\"ABX-123-Red-XYZ\",\"A\")": "BX-123-Red-XYZ",
// TEXTBEFORE
"=TEXTBEFORE(\"Red riding hood's, red hood\",\"hood\")": "Red riding ",
"=TEXTBEFORE(\"Red riding hood's, red hood\",\"HOOD\",1,1)": "Red riding ",
"=TEXTBEFORE(\"Red riding hood's, red hood\",\"basket\",1,0,0,\"x\")": "x",
"=TEXTBEFORE(\"Red riding hood's, red hood\",\"basket\",1,0,1,\"x\")": "Red riding hood's, red hood",
"=TEXTBEFORE(\"Red riding hood's, red hood\",\"hood\",-1)": "Red riding hood's, red ",
"=TEXTBEFORE(\"Jones,Bob\",\",\")": "Jones",
"=TEXTBEFORE(\"12 ft x 20 ft\",\" x \")": "12 ft",
"=TEXTBEFORE(\"ABX-112-Red-Y\",\"-\",1)": "ABX",
"=TEXTBEFORE(\"ABX-112-Red-Y\",\"-\",2)": "ABX-112",
"=TEXTBEFORE(\"ABX-112-Red-Y\",\"-\",-1)": "ABX-112-Red",
"=TEXTBEFORE(\"ABX-112-Red-Y\",\"-\",-2)": "ABX-112",
"=TEXTBEFORE(\"ABX-123-Red-XYZ\",\"-\",4,0,1)": "ABX-123-Red-XYZ",
"=TEXTBEFORE(\"ABX-112-Red-Y\",\"A\")": "",
// TEXTJOIN
"=TEXTJOIN(\"-\",TRUE,1,2,3,4)": "1-2-3-4",
"=TEXTJOIN(A4,TRUE,A1:B2)": "1040205",
@ -3879,6 +3908,24 @@ func TestCalcCellValue(t *testing.T) {
"=TEXT()": {"#VALUE!", "TEXT requires 2 arguments"},
"=TEXT(NA(),\"\")": {"#N/A", "#N/A"},
"=TEXT(0,NA())": {"#N/A", "#N/A"},
// TEXTAFTER
"=TEXTAFTER()": {"#VALUE!", "TEXTAFTER requires at least 2 arguments"},
"=TEXTAFTER(\"Red riding hood's, red hood\",\"hood\",1,0,0,\"\",0)": {"#VALUE!", "TEXTAFTER accepts at most 6 arguments"},
"=TEXTAFTER(\"Red riding hood's, red hood\",\"hood\",\"\")": {"#VALUE!", "strconv.ParseFloat: parsing \"\": invalid syntax"},
"=TEXTAFTER(\"Red riding hood's, red hood\",\"hood\",1,\"\")": {"#VALUE!", "strconv.ParseBool: parsing \"\": invalid syntax"},
"=TEXTAFTER(\"Red riding hood's, red hood\",\"hood\",1,0,\"\")": {"#VALUE!", "strconv.ParseBool: parsing \"\": invalid syntax"},
"=TEXTAFTER(\"\",\"hood\")": {"#N/A", "#N/A"},
"=TEXTAFTER(\"Red riding hood's, red hood\",\"hood\",0)": {"#VALUE!", "#VALUE!"},
"=TEXTAFTER(\"Red riding hood's, red hood\",\"hood\",28)": {"#VALUE!", "#VALUE!"},
// TEXTBEFORE
"=TEXTBEFORE()": {"#VALUE!", "TEXTBEFORE requires at least 2 arguments"},
"=TEXTBEFORE(\"Red riding hood's, red hood\",\"hood\",1,0,0,\"\",0)": {"#VALUE!", "TEXTBEFORE accepts at most 6 arguments"},
"=TEXTBEFORE(\"Red riding hood's, red hood\",\"hood\",\"\")": {"#VALUE!", "strconv.ParseFloat: parsing \"\": invalid syntax"},
"=TEXTBEFORE(\"Red riding hood's, red hood\",\"hood\",1,\"\")": {"#VALUE!", "strconv.ParseBool: parsing \"\": invalid syntax"},
"=TEXTBEFORE(\"Red riding hood's, red hood\",\"hood\",1,0,\"\")": {"#VALUE!", "strconv.ParseBool: parsing \"\": invalid syntax"},
"=TEXTBEFORE(\"\",\"hood\")": {"#N/A", "#N/A"},
"=TEXTBEFORE(\"Red riding hood's, red hood\",\"hood\",0)": {"#VALUE!", "#VALUE!"},
"=TEXTBEFORE(\"Red riding hood's, red hood\",\"hood\",28)": {"#VALUE!", "#VALUE!"},
// TEXTJOIN
"=TEXTJOIN()": {"#VALUE!", "TEXTJOIN requires at least 3 arguments"},
"=TEXTJOIN(\"\",\"\",1)": {"#VALUE!", "#VALUE!"},
@ -4739,9 +4786,27 @@ func TestCalcCompareFormulaArg(t *testing.T) {
rhs = newListFormulaArg([]formulaArg{newBoolFormulaArg(true)})
assert.Equal(t, compareFormulaArg(lhs, rhs, newNumberFormulaArg(matchModeMaxLess), false), criteriaEq)
lhs = newListFormulaArg([]formulaArg{newNumberFormulaArg(1)})
rhs = newListFormulaArg([]formulaArg{newNumberFormulaArg(0)})
assert.Equal(t, compareFormulaArg(lhs, rhs, newNumberFormulaArg(matchModeMaxLess), false), criteriaG)
assert.Equal(t, compareFormulaArg(formulaArg{Type: ArgUnknown}, formulaArg{Type: ArgUnknown}, newNumberFormulaArg(matchModeMaxLess), false), criteriaErr)
}
func TestCalcCompareFormulaArgMatrix(t *testing.T) {
lhs := newMatrixFormulaArg([][]formulaArg{{newEmptyFormulaArg()}})
rhs := newMatrixFormulaArg([][]formulaArg{{newEmptyFormulaArg(), newEmptyFormulaArg()}})
assert.Equal(t, compareFormulaArgMatrix(lhs, rhs, newNumberFormulaArg(matchModeMaxLess), false), criteriaL)
lhs = newMatrixFormulaArg([][]formulaArg{{newEmptyFormulaArg(), newEmptyFormulaArg()}})
rhs = newMatrixFormulaArg([][]formulaArg{{newEmptyFormulaArg()}})
assert.Equal(t, compareFormulaArgMatrix(lhs, rhs, newNumberFormulaArg(matchModeMaxLess), false), criteriaG)
lhs = newMatrixFormulaArg([][]formulaArg{{newNumberFormulaArg(1)}})
rhs = newMatrixFormulaArg([][]formulaArg{{newNumberFormulaArg(0)}})
assert.Equal(t, compareFormulaArgMatrix(lhs, rhs, newNumberFormulaArg(matchModeMaxLess), false), criteriaG)
}
func TestCalcTRANSPOSE(t *testing.T) {
cellData := [][]interface{}{
{"a", "d"},

View File

@ -343,7 +343,7 @@ func (f *File) addPivotTable(cacheID, pivotTableID int, pivotTableXML string, op
UseAutoFormatting: &opts.UseAutoFormatting,
PageOverThenDown: &opts.PageOverThenDown,
MergeItem: &opts.MergeItem,
CreatedVersion: 3,
CreatedVersion: pivotTableVersion,
CompactData: &opts.CompactData,
ShowError: &opts.ShowError,
DataCaption: "Values",