Skip to content

Commit 471c8f2

Browse files
committed
This closes qax-os#1160, and added 4 new formula functions
* Fix show sheet tabs issue * Ref qax-os#65, new formula functions: ERROR.TYPE, HOUR, SECOND TIMEVALUE
1 parent 9276419 commit 471c8f2

File tree

3 files changed

+208
-22
lines changed

3 files changed

+208
-22
lines changed

calc.go

Lines changed: 142 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -401,6 +401,7 @@ type formulaFuncs struct {
401401
// ERF.PRECISE
402402
// ERFC
403403
// ERFC.PRECISE
404+
// ERROR.TYPE
404405
// EVEN
405406
// EXACT
406407
// EXP
@@ -427,6 +428,7 @@ type formulaFuncs struct {
427428
// HEX2DEC
428429
// HEX2OCT
429430
// HLOOKUP
431+
// HOUR
430432
// IF
431433
// IFERROR
432434
// IFNA
@@ -574,6 +576,7 @@ type formulaFuncs struct {
574576
// RRI
575577
// SEC
576578
// SECH
579+
// SECOND
577580
// SHEET
578581
// SHEETS
579582
// SIGN
@@ -604,6 +607,7 @@ type formulaFuncs struct {
604607
// TBILLYIELD
605608
// TEXTJOIN
606609
// TIME
610+
// TIMEVALUE
607611
// TODAY
608612
// TRANSPOSE
609613
// TRIM
@@ -852,7 +856,9 @@ func (f *File) evalInfixExpFunc(sheet, cell string, token, nextToken efp.Token,
852856
// calculate trigger
853857
topOpt := opftStack.Peek().(efp.Token)
854858
if err := calculate(opfdStack, topOpt); err != nil {
855-
return err
859+
argsStack.Peek().(*list.List).PushBack(newErrorFormulaArg(err.Error(), err.Error()))
860+
opftStack.Pop()
861+
continue
856862
}
857863
opftStack.Pop()
858864
}
@@ -874,7 +880,11 @@ func (f *File) evalInfixExpFunc(sheet, cell string, token, nextToken efp.Token,
874880
if opfStack.Len() > 0 { // still in function stack
875881
if nextToken.TType == efp.TokenTypeOperatorInfix || (opftStack.Len() > 1 && opfdStack.Len() > 0) {
876882
// mathematics calculate in formula function
877-
opfdStack.Push(efp.Token{TValue: arg.Value(), TType: efp.TokenTypeOperand, TSubType: efp.TokenSubTypeNumber})
883+
if arg.Type == ArgError {
884+
opfdStack.Push(efp.Token{TValue: arg.Value(), TType: efp.TokenTypeOperand, TSubType: efp.TokenSubTypeError})
885+
} else {
886+
opfdStack.Push(efp.Token{TValue: arg.Value(), TType: efp.TokenTypeOperand, TSubType: efp.TokenSubTypeNumber})
887+
}
878888
} else {
879889
argsStack.Peek().(*list.List).PushBack(arg)
880890
}
@@ -1096,11 +1106,19 @@ func calculate(opdStack *Stack, opt efp.Token) error {
10961106
fn, ok := tokenCalcFunc[opt.TValue]
10971107
if ok {
10981108
if opdStack.Len() < 2 {
1109+
if opdStack.Len() == 1 {
1110+
rOpd := opdStack.Pop().(efp.Token)
1111+
if rOpd.TSubType == efp.TokenSubTypeError {
1112+
return errors.New(rOpd.TValue)
1113+
}
1114+
}
10991115
return ErrInvalidFormula
11001116
}
11011117
rOpd := opdStack.Pop().(efp.Token)
11021118
lOpd := opdStack.Pop().(efp.Token)
1103-
1119+
if lOpd.TSubType == efp.TokenSubTypeError {
1120+
return errors.New(lOpd.TValue)
1121+
}
11041122
if err := fn(rOpd, lOpd, opdStack); err != nil {
11051123
return err
11061124
}
@@ -4797,8 +4815,8 @@ func (fn *formulaFuncs) SUM(argsList *list.List) formulaArg {
47974815
for arg := argsList.Front(); arg != nil; arg = arg.Next() {
47984816
token := arg.Value.(formulaArg)
47994817
switch token.Type {
4800-
case ArgUnknown:
4801-
continue
4818+
case ArgError:
4819+
return token
48024820
case ArgString:
48034821
if num := token.ToNumber(); num.Type == ArgNumber {
48044822
sum += num.Number
@@ -6787,6 +6805,29 @@ func (fn *formulaFuncs) ZTEST(argsList *list.List) formulaArg {
67876805

67886806
// Information Functions
67896807

6808+
// ERRORdotTYPE function receives an error value and returns an integer, that
6809+
// tells you the type of the supplied error. The syntax of the function is:
6810+
//
6811+
// ERROR.TYPE(error_val)
6812+
//
6813+
func (fn *formulaFuncs) ERRORdotTYPE(argsList *list.List) formulaArg {
6814+
if argsList.Len() != 1 {
6815+
return newErrorFormulaArg(formulaErrorVALUE, "ERROR.TYPE requires 1 argument")
6816+
}
6817+
token := argsList.Front().Value.(formulaArg)
6818+
if token.Type == ArgError {
6819+
for i, errType := range []string{
6820+
formulaErrorNULL, formulaErrorDIV, formulaErrorVALUE, formulaErrorREF,
6821+
formulaErrorNAME, formulaErrorNUM, formulaErrorNA,
6822+
} {
6823+
if errType == token.String {
6824+
return newNumberFormulaArg(float64(i) + 1)
6825+
}
6826+
}
6827+
}
6828+
return newErrorFormulaArg(formulaErrorNA, formulaErrorNA)
6829+
}
6830+
67906831
// ISBLANK function tests if a specified cell is blank (empty) and if so,
67916832
// returns TRUE; Otherwise the function returns FALSE. The syntax of the
67926833
// function is:
@@ -7884,6 +7925,40 @@ func (fn *formulaFuncs) ISOWEEKNUM(argsList *list.List) formulaArg {
78847925
return newNumberFormulaArg(float64(weeknum))
78857926
}
78867927

7928+
// HOUR function returns an integer representing the hour component of a
7929+
// supplied Excel time. The syntax of the function is:
7930+
//
7931+
// HOUR(serial_number)
7932+
//
7933+
func (fn *formulaFuncs) HOUR(argsList *list.List) formulaArg {
7934+
if argsList.Len() != 1 {
7935+
return newErrorFormulaArg(formulaErrorVALUE, "HOUR requires exactly 1 argument")
7936+
}
7937+
date := argsList.Front().Value.(formulaArg)
7938+
num := date.ToNumber()
7939+
if num.Type != ArgNumber {
7940+
timeString := strings.ToLower(date.Value())
7941+
if !isTimeOnlyFmt(timeString) {
7942+
_, _, _, _, err := strToDate(timeString)
7943+
if err.Type == ArgError {
7944+
return err
7945+
}
7946+
}
7947+
h, _, _, pm, _, err := strToTime(timeString)
7948+
if err.Type == ArgError {
7949+
return err
7950+
}
7951+
if pm {
7952+
h += 12
7953+
}
7954+
return newNumberFormulaArg(float64(h))
7955+
}
7956+
if num.Number < 0 {
7957+
return newErrorFormulaArg(formulaErrorNUM, "HOUR only accepts positive argument")
7958+
}
7959+
return newNumberFormulaArg(float64(timeFromExcelTime(num.Number, false).Hour()))
7960+
}
7961+
78877962
// MINUTE function returns an integer representing the minute component of a
78887963
// supplied Excel time. The syntax of the function is:
78897964
//
@@ -8131,6 +8206,37 @@ func (fn *formulaFuncs) NOW(argsList *list.List) formulaArg {
81318206
return newNumberFormulaArg(25569.0 + float64(now.Unix()+int64(offset))/86400)
81328207
}
81338208

8209+
// SECOND function returns an integer representing the second component of a
8210+
// supplied Excel time. The syntax of the function is:
8211+
//
8212+
// SECOND(serial_number)
8213+
//
8214+
func (fn *formulaFuncs) SECOND(argsList *list.List) formulaArg {
8215+
if argsList.Len() != 1 {
8216+
return newErrorFormulaArg(formulaErrorVALUE, "SECOND requires exactly 1 argument")
8217+
}
8218+
date := argsList.Front().Value.(formulaArg)
8219+
num := date.ToNumber()
8220+
if num.Type != ArgNumber {
8221+
timeString := strings.ToLower(date.Value())
8222+
if !isTimeOnlyFmt(timeString) {
8223+
_, _, _, _, err := strToDate(timeString)
8224+
if err.Type == ArgError {
8225+
return err
8226+
}
8227+
}
8228+
_, _, s, _, _, err := strToTime(timeString)
8229+
if err.Type == ArgError {
8230+
return err
8231+
}
8232+
return newNumberFormulaArg(float64(int(s) % 60))
8233+
}
8234+
if num.Number < 0 {
8235+
return newErrorFormulaArg(formulaErrorNUM, "SECOND only accepts positive argument")
8236+
}
8237+
return newNumberFormulaArg(float64(timeFromExcelTime(num.Number, false).Second()))
8238+
}
8239+
81348240
// TIME function accepts three integer arguments representing hours, minutes
81358241
// and seconds, and returns an Excel time. I.e. the function returns the
81368242
// decimal value that represents the time in Excel. The syntax of the Time
@@ -8155,6 +8261,37 @@ func (fn *formulaFuncs) TIME(argsList *list.List) formulaArg {
81558261
return newNumberFormulaArg(t)
81568262
}
81578263

8264+
// TIMEVALUE function converts a text representation of a time, into an Excel
8265+
// time. The syntax of the Timevalue function is:
8266+
//
8267+
// TIMEVALUE(time_text)
8268+
//
8269+
func (fn *formulaFuncs) TIMEVALUE(argsList *list.List) formulaArg {
8270+
if argsList.Len() != 1 {
8271+
return newErrorFormulaArg(formulaErrorVALUE, "TIMEVALUE requires exactly 1 argument")
8272+
}
8273+
date := argsList.Front().Value.(formulaArg)
8274+
timeString := strings.ToLower(date.Value())
8275+
if !isTimeOnlyFmt(timeString) {
8276+
_, _, _, _, err := strToDate(timeString)
8277+
if err.Type == ArgError {
8278+
return err
8279+
}
8280+
}
8281+
h, m, s, pm, _, err := strToTime(timeString)
8282+
if err.Type == ArgError {
8283+
return err
8284+
}
8285+
if pm {
8286+
h += 12
8287+
}
8288+
args := list.New()
8289+
args.PushBack(newNumberFormulaArg(float64(h)))
8290+
args.PushBack(newNumberFormulaArg(float64(m)))
8291+
args.PushBack(newNumberFormulaArg(s))
8292+
return fn.TIME(args)
8293+
}
8294+
81588295
// TODAY function returns the current date. The function has no arguments and
81598296
// therefore. The syntax of the function is:
81608297
//

calc_test.go

Lines changed: 56 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -990,6 +990,12 @@ func TestCalcCellValue(t *testing.T) {
990990
"=WEIBULL.DIST(1,3,1,FALSE)": "1.103638323514327",
991991
"=WEIBULL.DIST(2,5,1.5,TRUE)": "0.985212776817482",
992992
// Information Functions
993+
// ERROR.TYPE
994+
"=ERROR.TYPE(1/0)": "2",
995+
"=ERROR.TYPE(COT(0))": "2",
996+
"=ERROR.TYPE(XOR(\"text\"))": "3",
997+
"=ERROR.TYPE(HEX2BIN(2,1))": "6",
998+
"=ERROR.TYPE(NA())": "7",
993999
// ISBLANK
9941000
"=ISBLANK(A1)": "FALSE",
9951001
"=ISBLANK(A5)": "TRUE",
@@ -1139,6 +1145,13 @@ func TestCalcCellValue(t *testing.T) {
11391145
"=DAYS(2,1)": "1",
11401146
"=DAYS(INT(2),INT(1))": "1",
11411147
"=DAYS(\"02/02/2015\",\"01/01/2015\")": "32",
1148+
// HOUR
1149+
"=HOUR(1)": "0",
1150+
"=HOUR(43543.5032060185)": "12",
1151+
"=HOUR(\"43543.5032060185\")": "12",
1152+
"=HOUR(\"13:00:55\")": "13",
1153+
"=HOUR(\"1:00 PM\")": "13",
1154+
"=HOUR(\"12/09/2015 08:55\")": "8",
11421155
// ISOWEEKNUM
11431156
"=ISOWEEKNUM(42370)": "53",
11441157
"=ISOWEEKNUM(\"42370\")": "53",
@@ -1183,10 +1196,26 @@ func TestCalcCellValue(t *testing.T) {
11831196
"=YEARFRAC(\"02/29/2000\", \"01/29/2001\",1)": "0.915300546448087",
11841197
"=YEARFRAC(\"02/29/2000\", \"03/29/2000\",1)": "0.0792349726775956",
11851198
"=YEARFRAC(\"01/31/2000\", \"03/29/2000\",4)": "0.163888888888889",
1199+
// SECOND
1200+
"=SECOND(\"13:35:55\")": "55",
1201+
"=SECOND(\"13:10:60\")": "0",
1202+
"=SECOND(\"13:10:61\")": "1",
1203+
"=SECOND(\"08:17:00\")": "0",
1204+
"=SECOND(\"12/09/2015 08:55\")": "0",
1205+
"=SECOND(\"12/09/2011 08:17:23\")": "23",
1206+
"=SECOND(\"43543.5032060185\")": "37",
1207+
"=SECOND(43543.5032060185)": "37",
11861208
// TIME
11871209
"=TIME(5,44,32)": "0.239259259259259",
11881210
"=TIME(\"5\",\"44\",\"32\")": "0.239259259259259",
11891211
"=TIME(0,0,73)": "0.000844907407407407",
1212+
// TIMEVALUE
1213+
"=TIMEVALUE(\"2:23\")": "0.0993055555555556",
1214+
"=TIMEVALUE(\"2:23 am\")": "0.0993055555555556",
1215+
"=TIMEVALUE(\"2:23 PM\")": "0.599305555555555",
1216+
"=TIMEVALUE(\"14:23:00\")": "0.599305555555555",
1217+
"=TIMEVALUE(\"00:02:23\")": "0.00165509259259259",
1218+
"=TIMEVALUE(\"01/01/2011 02:23\")": "0.0993055555555556",
11901219
// WEEKDAY
11911220
"=WEEKDAY(0)": "7",
11921221
"=WEEKDAY(47119)": "2",
@@ -2167,12 +2196,14 @@ func TestCalcCellValue(t *testing.T) {
21672196
"=POISSON(0,0,\"\")": "strconv.ParseBool: parsing \"\": invalid syntax",
21682197
"=POISSON(0,-1,TRUE)": "#N/A",
21692198
// SUM
2170-
"=SUM((": ErrInvalidFormula.Error(),
2171-
"=SUM(-)": ErrInvalidFormula.Error(),
2172-
"=SUM(1+)": ErrInvalidFormula.Error(),
2173-
"=SUM(1-)": ErrInvalidFormula.Error(),
2174-
"=SUM(1*)": ErrInvalidFormula.Error(),
2175-
"=SUM(1/)": ErrInvalidFormula.Error(),
2199+
"=SUM((": ErrInvalidFormula.Error(),
2200+
"=SUM(-)": ErrInvalidFormula.Error(),
2201+
"=SUM(1+)": ErrInvalidFormula.Error(),
2202+
"=SUM(1-)": ErrInvalidFormula.Error(),
2203+
"=SUM(1*)": ErrInvalidFormula.Error(),
2204+
"=SUM(1/)": ErrInvalidFormula.Error(),
2205+
"=SUM(1*SUM(1/0))": "#DIV/0!",
2206+
"=SUM(1*SUM(1/0)*1)": "#DIV/0!",
21762207
// SUMIF
21772208
"=SUMIF()": "SUMIF requires at least 2 arguments",
21782209
// SUMSQ
@@ -2453,6 +2484,9 @@ func TestCalcCellValue(t *testing.T) {
24532484
"=ZTEST(A1,1)": "#DIV/0!",
24542485
"=ZTEST(A1,1,\"\")": "strconv.ParseFloat: parsing \"\": invalid syntax",
24552486
// Information Functions
2487+
// ERROR.TYPE
2488+
"=ERROR.TYPE()": "ERROR.TYPE requires 1 argument",
2489+
"=ERROR.TYPE(1)": "#N/A",
24562490
// ISBLANK
24572491
"=ISBLANK(A1,A2)": "ISBLANK requires 1 argument",
24582492
// ISERR
@@ -2582,6 +2616,11 @@ func TestCalcCellValue(t *testing.T) {
25822616
"=DAYS(0,\"\")": "#VALUE!",
25832617
"=DAYS(NA(),0)": "#VALUE!",
25842618
"=DAYS(0,NA())": "#VALUE!",
2619+
// HOUR
2620+
"=HOUR()": "HOUR requires exactly 1 argument",
2621+
"=HOUR(-1)": "HOUR only accepts positive argument",
2622+
"=HOUR(\"\")": "#VALUE!",
2623+
"=HOUR(\"25:10:55\")": "#VALUE!",
25852624
// ISOWEEKNUM
25862625
"=ISOWEEKNUM()": "ISOWEEKNUM requires 1 argument",
25872626
"=ISOWEEKNUM(\"\")": "#VALUE!",
@@ -2612,10 +2651,20 @@ func TestCalcCellValue(t *testing.T) {
26122651
"=YEARFRAC(42005,42094,\"\")": "strconv.ParseFloat: parsing \"\": invalid syntax",
26132652
// NOW
26142653
"=NOW(A1)": "NOW accepts no arguments",
2654+
// SECOND
2655+
"=SECOND()": "SECOND requires exactly 1 argument",
2656+
"=SECOND(-1)": "SECOND only accepts positive argument",
2657+
"=SECOND(\"\")": "#VALUE!",
2658+
"=SECOND(\"25:55\")": "#VALUE!",
26152659
// TIME
26162660
"=TIME()": "TIME requires 3 number arguments",
26172661
"=TIME(\"\",0,0)": "TIME requires 3 number arguments",
26182662
"=TIME(0,0,-1)": "#NUM!",
2663+
// TIMEVALUE
2664+
"=TIMEVALUE()": "TIMEVALUE requires exactly 1 argument",
2665+
"=TIMEVALUE(1)": "#VALUE!",
2666+
"=TIMEVALUE(-1)": "#VALUE!",
2667+
"=TIMEVALUE(\"25:55\")": "#VALUE!",
26192668
// TODAY
26202669
"=TODAY(A1)": "TODAY accepts no arguments",
26212670
// WEEKDAY
@@ -3354,7 +3403,7 @@ func TestCalcCellValue(t *testing.T) {
33543403
f := prepareCalcData(cellData)
33553404
assert.NoError(t, f.SetCellFormula("Sheet1", "C1", formula))
33563405
result, err := f.CalcCellValue("Sheet1", "C1")
3357-
assert.EqualError(t, err, expected)
3406+
assert.EqualError(t, err, expected, formula)
33583407
assert.Equal(t, "", result, formula)
33593408
}
33603409

xmlWorkbook.go

Lines changed: 10 additions & 10 deletions
Original file line numberDiff line numberDiff line change
@@ -139,19 +139,19 @@ type xlsxBookViews struct {
139139
// http://schemas.openxmlformats.org/spreadsheetml/2006/main This element
140140
// specifies a single Workbook view.
141141
type xlsxWorkBookView struct {
142-
ActiveTab int `xml:"activeTab,attr,omitempty"`
143-
AutoFilterDateGrouping bool `xml:"autoFilterDateGrouping,attr,omitempty"`
144-
FirstSheet int `xml:"firstSheet,attr,omitempty"`
145-
Minimized bool `xml:"minimized,attr,omitempty"`
146-
ShowHorizontalScroll bool `xml:"showHorizontalScroll,attr,omitempty"`
147-
ShowSheetTabs bool `xml:"showSheetTabs,attr,omitempty"`
148-
ShowVerticalScroll bool `xml:"showVerticalScroll,attr,omitempty"`
149-
TabRatio int `xml:"tabRatio,attr,omitempty"`
150142
Visibility string `xml:"visibility,attr,omitempty"`
151-
WindowHeight int `xml:"windowHeight,attr,omitempty"`
152-
WindowWidth int `xml:"windowWidth,attr,omitempty"`
143+
Minimized bool `xml:"minimized,attr,omitempty"`
144+
ShowHorizontalScroll *bool `xml:"showHorizontalScroll,attr"`
145+
ShowVerticalScroll *bool `xml:"showVerticalScroll,attr"`
146+
ShowSheetTabs *bool `xml:"showSheetTabs,attr"`
153147
XWindow string `xml:"xWindow,attr,omitempty"`
154148
YWindow string `xml:"yWindow,attr,omitempty"`
149+
WindowWidth int `xml:"windowWidth,attr,omitempty"`
150+
WindowHeight int `xml:"windowHeight,attr,omitempty"`
151+
TabRatio int `xml:"tabRatio,attr,omitempty"`
152+
FirstSheet int `xml:"firstSheet,attr,omitempty"`
153+
ActiveTab int `xml:"activeTab,attr,omitempty"`
154+
AutoFilterDateGrouping *bool `xml:"autoFilterDateGrouping,attr"`
155155
}
156156

157157
// xlsxSheets directly maps the sheets element from the namespace

0 commit comments

Comments
 (0)