Spreadsheed Formula Functions (#345)

* CELL function
* CELL moved to fninformation.go
* CHOOSE function
* CHOOSE function add one test
* COLUMN function
* COLUMNS function
* COUNTIF function
* COUNTIF, COUNTIFS, MINIFS, MAXIFS, SUMIF, SUMIFS, some style fixes
* SUMIF and SUMIFS moved to the right location
* VALUE function
* wildcard is added
* CELL format fix
This commit is contained in:
Vyacheslav Zgordan 2019-11-05 19:36:09 +03:00 committed by Gunnsteinn Hall
parent a0ab7d537f
commit 415c045839
13 changed files with 1350 additions and 8 deletions

View File

@ -0,0 +1,83 @@
/*
* MinIO Cloud Storage, (C) 2015, 2016 MinIO, Inc.
*
* Licensed under the Apache License, Version 2.0 (the "License");
* you may not use this file except in compliance with the License.
* You may obtain a copy of the License at
*
* http://www.apache.org/licenses/LICENSE-2.0
*
* Unless required by applicable law or agreed to in writing, software
* distributed under the License is distributed on an "AS IS" BASIS,
* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
* See the License for the specific language governing permissions and
* limitations under the License.
*/
package wildcard
// MatchSimple - finds whether the text matches/satisfies the pattern string.
// supports only '*' wildcard in the pattern.
// considers a file system path as a flat name space.
func MatchSimple(pattern, name string) bool {
if pattern == "" {
return name == pattern
}
if pattern == "*" {
return true
}
rname := make([]rune, 0, len(name))
rpattern := make([]rune, 0, len(pattern))
for _, r := range name {
rname = append(rname, r)
}
for _, r := range pattern {
rpattern = append(rpattern, r)
}
simple := true // Does only wildcard '*' match.
return deepMatchRune(rname, rpattern, simple)
}
// Match - finds whether the text matches/satisfies the pattern string.
// supports '*' and '?' wildcards in the pattern string.
// unlike path.Match(), considers a path as a flat name space while matching the pattern.
// The difference is illustrated in the example here https://play.golang.org/p/Ega9qgD4Qz .
func Match(pattern, name string) (matched bool) {
if pattern == "" {
return name == pattern
}
if pattern == "*" {
return true
}
rname := make([]rune, 0, len(name))
rpattern := make([]rune, 0, len(pattern))
for _, r := range name {
rname = append(rname, r)
}
for _, r := range pattern {
rpattern = append(rpattern, r)
}
simple := false // Does extended wildcard '*' and '?' match.
return deepMatchRune(rname, rpattern, simple)
}
func deepMatchRune(str, pattern []rune, simple bool) bool {
for len(pattern) > 0 {
switch pattern[0] {
default:
if len(str) == 0 || str[0] != pattern[0] {
return false
}
case '?':
if len(str) == 0 && !simple {
return false
}
case '*':
return deepMatchRune(str, pattern[1:], simple) ||
(len(str) > 0 && deepMatchRune(str[1:], pattern, simple))
}
str = str[1:]
pattern = pattern[1:]
}
return len(str) == 0 && len(pattern) == 0
}

View File

@ -191,6 +191,30 @@ func (c Cell) getFormat() string {
return nf.GetFormat()
}
func (c Cell) getLabelPrefix() string {
if c.x.SAttr == nil {
return ""
}
sid := *c.x.SAttr
cs := c.w.StyleSheet.GetCellStyle(sid)
switch cs.xf.Alignment.HorizontalAttr {
case sml.ST_HorizontalAlignmentLeft: return "'"
case sml.ST_HorizontalAlignmentRight: return "\""
case sml.ST_HorizontalAlignmentCenter: return "^"
case sml.ST_HorizontalAlignmentFill: return "\\"
default: return ""
}
}
func (c Cell) getLocked() bool {
if c.x.SAttr == nil {
return false
}
sid := *c.x.SAttr
f := c.w.StyleSheet.GetCellStyle(sid)
return *f.xf.Protection.LockedAttr
}
// GetFormattedValue returns the formatted cell value as it would appear in
// Excel. This involves determining the format string to apply, parsing it, and
// then formatting the value according to the format string. This should only
@ -553,6 +577,17 @@ func (c Cell) SetCachedFormulaResult(s string) {
c.x.V = &s
}
func (c Cell) setLocked(locked bool) {
sid := c.x.SAttr
if sid != nil {
f := c.w.StyleSheet.GetCellStyle(*sid)
if f.xf.Protection == nil {
f.xf.Protection = sml.NewCT_CellProtection()
}
f.xf.Protection.LockedAttr = &locked
}
}
func b2i(v bool) int {
if v {
return 1

View File

@ -95,3 +95,39 @@ func (e *evalContext) SetOffset(col, row uint32) {
e.colOff = col
e.rowOff = row
}
// GetFilename returns the filename of the context's workbook.
func (e *evalContext) GetFilename() string {
return e.s.w.GetFilename()
}
// GetFormat returns a cell data format.
func (e *evalContext) GetFormat(cellRef string) string {
return e.s.Cell(cellRef).getFormat()
}
// GetLabelPrefix returns label prefix which depends on the cell's horizontal alignment.
func (e *evalContext) GetLabelPrefix(cellRef string) string {
return e.s.Cell(cellRef).getLabelPrefix()
}
// GetLocked returns if the cell is locked.
func (e *evalContext) GetLocked(cellRef string) bool {
return e.s.Cell(cellRef).getLocked()
}
// SetLocked sets cell locked or not.
func (e *evalContext) SetLocked(cellRef string, locked bool) {
e.s.Cell(cellRef).setLocked(locked)
}
// GetWidth returns a worksheet's column width.
func (e *evalContext) GetWidth(colIdx int) float64 {
colIdx++
for _, c := range e.s.X().Cols[0].Col {
if int(c.MinAttr) <= colIdx && colIdx <= int(c.MaxAttr) {
return float64(int(*c.WidthAttr))
}
}
return 0
}

View File

@ -14,9 +14,27 @@ type Context interface {
Cell(ref string, ev Evaluator) Result
// Sheet returns an evaluation context for a given sheet name. This is used
// when evaluating cells that pull data from other sheets (e.g. ='Sheet 2'!A1)
// when evaluating cells that pull data from other sheets (e.g. ='Sheet 2'!A1).
Sheet(name string) Context
// GetFilename returns the full filename of the context's Workbook.
GetFilename() string
// GetWidth returns a worksheet's column width.
GetWidth(colIdx int) float64
// GetFormat returns a cell's format.
GetFormat(cellRef string) string
// GetLabelPrefix returns cell's label prefix dependent on cell horizontal alignment.
GetLabelPrefix(cellRef string) string
// GetFormat returns if cell is protected.
GetLocked(cellRef string) bool
// GetFormat returns sets cell's protected attribute.
SetLocked(cellRef string, locked bool)
// NamedRange returns a named range.
NamedRange(name string) Reference

View File

@ -15,6 +15,9 @@ import (
)
func init() {
RegisterFunction("CHOOSE", Choose)
RegisterFunction("COLUMN", Column)
RegisterFunction("COLUMNS", Columns)
RegisterFunction("INDEX", Index)
RegisterFunctionComplex("INDIRECT", Indirect)
RegisterFunctionComplex("OFFSET", Offset)
@ -24,7 +27,55 @@ func init() {
RegisterFunction("TRANSPOSE", Transpose)
}
// Index implements the Excel INDEX function
// Choose implements the Excel CHOOSE function.
func Choose(args []Result) Result {
if len(args) < 2 {
return MakeErrorResult("CHOOSE requires two arguments")
}
index := args[0]
if index.Type != ResultTypeNumber {
return MakeErrorResult("CHOOSE requires first argument of type number")
}
i := int(index.ValueNumber)
if len(args) <= i {
return MakeErrorResult("Index should be less or equal to the number of values")
}
return args[i]
}
// Column implements the Excel COLUMN function.
func Column(args []Result) Result {
if len(args) < 1 {
return MakeErrorResult("COLUMN requires one argument")
}
ref := args[0].Ref
if ref.Type != ReferenceTypeCell {
return MakeErrorResult("COLUMN requires an argument to be of type reference")
}
cr, err := reference.ParseCellReference(ref.Value)
if err != nil {
return MakeErrorResult("Incorrect reference: " + ref.Value)
}
return MakeNumberResult(float64(cr.ColumnIdx+1))
}
// Columns implements the Excel COLUMNS function.
func Columns(args []Result) Result {
if len(args) < 1 {
return MakeErrorResult("COLUMNS requires one argument")
}
arrResult := args[0]
if arrResult.Type != ResultTypeArray && arrResult.Type != ResultTypeList {
return MakeErrorResult("COLUMNS requires first argument of type array")
}
arr := arrResult.ValueArray
if len(arr) == 0 {
return MakeErrorResult("COLUMNS requires array to contain at least 1 row")
}
return MakeNumberResult(float64(len(arr[0])))
}
// Index implements the Excel INDEX function.
func Index(args []Result) Result {
if len(args) < 3 {
return MakeErrorResult("INDEX requires three arguments")
@ -81,6 +132,7 @@ func Indirect(ctx Context, ev Evaluator, args []Result) Result {
return ctx.Cell(sarg.ValueString, ev)
}
// Offset is an implementation of the Excel OFFSET function.
func Offset(ctx Context, ev Evaluator, args []Result) Result {
if len(args) != 5 {
return MakeErrorResult("OFFSET requires one or two arguments")

View File

@ -7,8 +7,39 @@
package formula
import (
"regexp"
"strconv"
"strings"
"github.com/unidoc/unioffice/spreadsheet/reference"
)
func init() {
initRegexpInformation()
RegisterFunction("NA", NA)
RegisterFunctionComplex("CELL", Cell)
}
var bs string = string([]byte{92})
var integer, finance, intSep, intPar, decimal, decJust, decPar, par, percent, intCur, cur, curLabel, mdy, dmy, sci *regexp.Regexp
func initRegexpInformation() {
integer = regexp.MustCompile(`^0+$`) // 12345
intSep = regexp.MustCompile("^((#|0)+,)+(#|0)+(;|$)") // 123,456,789
intPar = regexp.MustCompile("^(#|0|,)*_\\);") // (123,456,789)
finance = regexp.MustCompile("^0+\\.(0+)$") // 1.23
decimal = regexp.MustCompile("^((#|0)+,)+(#|0)+\\.(0+).*(;|$)") // 1.234
decJust = regexp.MustCompile("^(_|-| )+\\* #+,#+0\\.(0+).*;") // 1.234 with justified horizontal alignment
decPar = regexp.MustCompile("^((#|0)+,)+(#|0)+\\.((#|0)+)_\\).*;") // (1.234)
percent = regexp.MustCompile("^(#|0)+\\.((#|0)+)%$") // 12.34%
intCur = regexp.MustCompile("\\[\\$\\$-.+\\](\\* )?(#|0)+,(#|0)+;") // $1,234
cur = regexp.MustCompile("\\[\\$\\$-.+\\](\\* )?(#|0)+,(#|0)+\\.((#|0|-)+).*;") // $1,234.56
curLabel = regexp.MustCompile("^((#|0)+,)+(#|0)+(\\.((#|0|-)+))?.+\\[\\$.+\\].*;") // 1,234.56 USD
mdy = regexp.MustCompile("^M+(/| |,|\"|" + bs + bs + ")+D+(/| |,|\"|" + bs + bs + ")+Y+$") // 01/21/2019
dmy = regexp.MustCompile("^D+(/| |\\.|\"|" + bs + bs + ")+M+(/| |\\.|\"|" + bs + bs + ")+Y+$") // 21. Jan. 2019
sci = regexp.MustCompile("^(#|0)+\\.((#|0)*)E\\+(#|0)+(;|$)") // 1.02E+002
par = regexp.MustCompile("^.*_\\).*;") // (anything in parentheses)
}
// NA is an implementation of the Excel NA() function that just returns the #N/A! error.
@ -18,3 +49,136 @@ func NA(args []Result) Result {
}
return MakeErrorResultType(ErrorTypeNA, "")
}
// Cell is an implementation of the Excel CELL function that returns information
// about the formatting, location, or contents of a cell.
func Cell(ctx Context, ev Evaluator, args []Result) Result {
if len(args) != 1 && len(args) != 2 {
return MakeErrorResult("CELL requires one or two arguments")
}
typ := args[0].AsString()
if typ.Type != ResultTypeString {
return MakeErrorResult("CELL requires first argument to be of type string")
}
ref := args[1].Ref
if ref.Type != ReferenceTypeCell {
return MakeErrorResult("CELL requires second argument to be of type reference")
}
refStr := ref.Value
switch typ.ValueString {
case "address":
cr, err := reference.ParseCellReference(refStr)
if err != nil {
return MakeErrorResult("Incorrect reference: " + refStr)
}
address := "$"+cr.Column+"$"+strconv.Itoa(int(cr.RowIdx))
return MakeStringResult(address)
case "col":
cr, err := reference.ParseCellReference(refStr)
if err != nil {
return MakeErrorResult("Incorrect reference: " + refStr)
}
return MakeNumberResult(float64(cr.ColumnIdx+1))
case "color":
red := strings.Contains(ctx.GetFormat(refStr), "[RED]")
return MakeBoolResult(red)
case "contents":
return args[1]
case "filename":
return MakeStringResult(ctx.GetFilename())
case "format":
result := "G"
format := ctx.GetFormat(refStr)
if format == "General" || integer.MatchString(format) {
result = "F0"
} else if format == "0%" {
result = "P0"
} else if format == "MMM DD" {
result = "D2"
} else if format == "MM/YY" {
result = "D3"
} else if format == "MM/DD/YY\\ HH:MM\\ AM/PM" || format == "MM/DD/YYYY\\ HH:MM:SS" {
result = "D4"
} else if format == "MM\\-DD" {
result = "D5"
} else if format == "HH:MM:SS\\ AM/PM" {
result = "D6"
} else if format == "HH:MM\\ AM/PM" {
result = "D7"
} else if format == "HH:MM:SS" {
result = "D8"
} else if format == "HH:MM" {
result = "D9"
} else if intSep.MatchString(format) {
result = ".0"
} else if intPar.MatchString(format) {
result = ".0()"
} else if intCur.MatchString(format) {
result = "C0"
} else if mdy.MatchString(format) || dmy.MatchString(format) {
result = "D1"
} else if submatch := finance.FindStringSubmatch(format); len(submatch) > 1 {
result = "F" + strconv.Itoa(len(submatch[1]))
} else if submatch := decJust.FindStringSubmatch(format); len(submatch) > 1 {
result = "." + strconv.Itoa(len(submatch[2]))
} else if submatch := percent.FindStringSubmatch(format); len(submatch) > 1 {
result = "P" + strconv.Itoa(len(submatch[2]))
} else if submatch := cur.FindStringSubmatch(format); len(submatch) > 1 {
result = "C" + itemFromEndLength(submatch, 1)
} else if submatch := curLabel.FindStringSubmatch(format); len(submatch) > 1 {
result = "C" + itemFromEndLength(submatch, 1)
} else if submatch := decPar.FindStringSubmatch(format); len(submatch) > 1 {
result = "." + itemFromEndLength(submatch, 1) + "()"
} else if submatch := decimal.FindStringSubmatch(format); len(submatch) > 1 {
result = "." + itemFromEndLength(submatch, 1)
} else if submatch := sci.FindStringSubmatch(format); len(submatch) > 1 {
result = "S" + itemFromEndLength(submatch, 3)
}
if result != "G" && strings.Contains(format, "[RED]") {
result += "-"
}
return MakeStringResult(result)
case "parentheses":
format := ctx.GetFormat(refStr)
if par.MatchString(format) {
return MakeNumberResult(1)
} else {
return MakeNumberResult(0)
}
case "prefix":
return MakeStringResult(ctx.GetLabelPrefix(refStr))
case "protect":
result := 0.0
if ctx.GetLocked(refStr) {
result = 1.0
}
return MakeNumberResult(result)
case "row":
cr, err := reference.ParseCellReference(refStr)
if err != nil {
return MakeErrorResult("Incorrect reference: " + refStr)
}
return MakeNumberResult(float64(cr.RowIdx))
case "type":
switch args[1].Type {
case ResultTypeEmpty:
return MakeStringResult("b")
case ResultTypeString:
return MakeStringResult("l")
default:
return MakeStringResult("v")
}
case "width":
cr, err := reference.ParseCellReference(refStr)
if err != nil {
return MakeErrorResult("Incorrect reference: " + refStr)
}
return MakeNumberResult(ctx.GetWidth(int(cr.ColumnIdx)))
}
return MakeErrorResult("Incorrect first argument of CELL: "+typ.ValueString)
}
func itemFromEndLength(submatch []string, additionalShift int) string {
return strconv.Itoa(len(submatch[len(submatch)-1-additionalShift]))
}

View File

@ -90,9 +90,8 @@ func init() {
RegisterFunction("SQRTPI", makeMathWrapper("SQRTPI", func(v float64) float64 { return math.Sqrt(v * math.Pi) }))
// RegisterFunction("SUBTOTAL"
RegisterFunction("SUM", Sum)
// RegisterFunction("SUMIF",
// RegisterFunction("SUMIFS",
// RegisterFunction("SUMIFS",
RegisterFunction("SUMIF", SumIf)
RegisterFunction("SUMIFS", SumIfs)
RegisterFunction("SUMPRODUCT", SumProduct)
RegisterFunction("SUMSQ", SumSquares)
//RegisterFunction("SUMX2MY2"
@ -1515,6 +1514,51 @@ func Sum(args []Result) Result {
return res
}
// SumIf implements the SUMIF function.
func SumIf(args []Result) Result {
if len(args) < 3 {
return MakeErrorResult("SUMIF requires three arguments")
}
arrResult := args[0]
if arrResult.Type != ResultTypeArray && arrResult.Type != ResultTypeList {
return MakeErrorResult("SUMIF requires first argument of type array")
}
arr := arrayFromRange(arrResult)
sumArrResult := args[2]
if sumArrResult.Type != ResultTypeArray && sumArrResult.Type != ResultTypeList {
return MakeErrorResult("SUMIF requires last argument of type array")
}
sumArr := arrayFromRange(sumArrResult)
criteria := parseCriteria(args[1])
sum := 0.0
for ir, r := range arr {
for ic, value := range r {
if compare(value, criteria) {
sum += sumArr[ir][ic].ValueNumber
}
}
}
return MakeNumberResult(sum)
}
// SumIfs implements the SUMIFS function.
func SumIfs(args []Result) Result {
errorResult := checkIfsRanges(args, true, "SUMIFS")
if errorResult.Type != ResultTypeEmpty {
return errorResult
}
match := getIfsMatch(args[1:])
sum := 0.0
sumArr := arrayFromRange(args[0])
for _, indexes := range match {
sum += sumArr[indexes.rowIndex][indexes.colIndex].ValueNumber
}
return MakeNumberResult(float64(sum))
}
// SumProduct is an implementation of the Excel SUMPRODUCT() function.
func SumProduct(args []Result) Result {
if len(args) == 0 {

View File

@ -9,20 +9,42 @@ package formula
import (
"math"
"regexp"
"sort"
"strconv"
"strings"
"github.com/unidoc/unioffice"
"github.com/unidoc/unioffice/internal/wildcard"
)
func init() {
initRegexpStatistical()
RegisterFunction("AVERAGE", Average)
RegisterFunction("AVERAGEA", Averagea)
RegisterFunction("COUNT", Count)
RegisterFunction("COUNTA", Counta)
RegisterFunction("COUNTIF", CountIf)
RegisterFunction("COUNTIFS", CountIfs)
RegisterFunction("COUNTBLANK", CountBlank)
RegisterFunction("MAX", Max)
RegisterFunction("MIN", Min)
RegisterFunction("MAXIFS", MaxIfs)
RegisterFunction("_xlfn.MAXIFS", MaxIfs)
RegisterFunction("MEDIAN", Median)
RegisterFunction("MIN", Min)
RegisterFunction("MINIFS", MinIfs)
RegisterFunction("_xlfn.MINIFS", MinIfs)
}
var number, eq, g, l, ge, le *regexp.Regexp
func initRegexpStatistical() {
number = regexp.MustCompile(`^([0-9]+)$`)
eq = regexp.MustCompile(`^=(.*)$`) // =-12345.67, =A6
l = regexp.MustCompile(`^<(.*)$`) // <-12345.67, <A6
g = regexp.MustCompile(`^>(.*)$`) // >-12345.67, >A6
le = regexp.MustCompile(`^<=(.*)$`) // <=-12345.67, <=A6
ge = regexp.MustCompile(`^>=(.*)$`) // >=-12345.67, >=A6
}
func sumCount(args []Result, countText bool) (float64, float64) {
@ -121,6 +143,230 @@ func CountBlank(args []Result) Result {
return MakeNumberResult(count(args, countEmpty))
}
type criteriaParsed struct {
isNumber bool
cNum float64
cStr string
cRegex *criteriaRegex
}
const (
_ byte = iota
isEq
isLe
isGe
isL
isG
)
type criteriaRegex struct {
regexType byte // type of condition
compareWith string // value to apply condition to
}
func parseCriteria(criteria Result) *criteriaParsed {
isNumber := criteria.Type == ResultTypeNumber
cNum := criteria.ValueNumber
cStr := strings.ToLower(criteria.ValueString)
cRegex := parseCriteriaRegex(cStr)
return &criteriaParsed{
isNumber,
cNum,
cStr,
cRegex,
}
}
func parseCriteriaRegex(cStr string) *criteriaRegex {
cRegex := &criteriaRegex{}
if cStr == "" {
return cRegex
}
if submatch := number.FindStringSubmatch(cStr); len(submatch) > 1 {
cRegex.regexType = isEq
cRegex.compareWith = submatch[1]
} else if submatch := eq.FindStringSubmatch(cStr); len(submatch) > 1 {
cRegex.regexType = isEq
cRegex.compareWith = submatch[1]
} else if submatch := le.FindStringSubmatch(cStr); len(submatch) > 1 {
cRegex.regexType = isLe
cRegex.compareWith = submatch[1]
} else if submatch := ge.FindStringSubmatch(cStr); len(submatch) > 1 {
cRegex.regexType = isGe
cRegex.compareWith = submatch[1]
} else if submatch := l.FindStringSubmatch(cStr); len(submatch) > 1 {
cRegex.regexType = isL
cRegex.compareWith = submatch[1]
} else if submatch := g.FindStringSubmatch(cStr); len(submatch) > 1 {
cRegex.regexType = isG
cRegex.compareWith = submatch[1]
}
return cRegex
}
// CountIf implements the COUNTIF function.
func CountIf(args []Result) Result {
if len(args) < 2 {
return MakeErrorResult("COUNTIF requires two argumentss")
}
arr := args[0]
if arr.Type != ResultTypeArray && arr.Type != ResultTypeList {
return MakeErrorResult("COUNTIF requires first argument of type array")
}
criteria := parseCriteria(args[1])
count := 0
for _, r := range arrayFromRange(arr) {
for _, value := range r {
if compare(value, criteria) {
count++
}
}
}
return MakeNumberResult(float64(count))
}
func arrayFromRange(result Result) [][]Result {
switch result.Type {
case ResultTypeArray:
return result.ValueArray
case ResultTypeList:
return [][]Result{
result.ValueList,
}
default:
return [][]Result{}
}
}
// helper type for storing indexes of found values
type rangeIndex struct {
rowIndex int
colIndex int
}
func checkIfsRanges(args []Result, sumRange bool, fnName string) Result {
// quick check before searching
var minArgs, oddEven string
if sumRange {
minArgs = "three"
oddEven = "odd"
} else {
minArgs = "two"
oddEven = "even"
}
argsNum := len(args)
if (sumRange && argsNum < 3) || (!sumRange && argsNum < 2) {
return MakeErrorResult(fnName + " requires at least " + minArgs + " argumentss")
}
if (argsNum/2*2 == argsNum) == sumRange {
return MakeErrorResult(fnName + " requires " + oddEven + " number of arguments")
}
rangeWidth := -1
rangeHeight := -1
for i := 0; i < argsNum; i+=2 {
arrResult := args[i]
if arrResult.Type != ResultTypeArray && arrResult.Type != ResultTypeList {
return MakeErrorResult(fnName + " requires ranges of type list or array")
}
arr := arrayFromRange(arrResult)
if rangeHeight == -1 {
rangeHeight = len(arr)
rangeWidth = len(arr[0])
} else if len(arr) != rangeHeight || len(arr[0]) != rangeWidth {
return MakeErrorResult(fnName + " requires all ranges to be of the same size")
}
if sumRange && i == 0 {
i-- // after sumRange should go column 1, not 2
}
}
return MakeEmptyResult()
}
//getIfsMatch returns an array of indexes of cells which meets all *IFS criterias
func getIfsMatch(args []Result) []rangeIndex {
toLook := []rangeIndex{}
argsNum := len(args)
for i := 0; i < argsNum-1; i+=2 {
found := []rangeIndex{}
arr := arrayFromRange(args[i])
criteria := parseCriteria(args[i+1])
if i == 0 {
for rowIndex, row := range arr { // for the first range look in every cell of the range
for colIndex, value := range row {
if compare(value, criteria) {
found = append(found, rangeIndex{rowIndex, colIndex})
}
}
}
} else {
for _, index2d := range toLook { // for next ranges look only in cells of the range in which values matched for the previous range
value := arr[index2d.rowIndex][index2d.colIndex]
if compare(value, criteria) {
found = append(found, index2d)
}
}
}
if len(found) == 0 { // if nothing found at some step no sense to continue
return []rangeIndex{}
}
toLook = found[:] // next time look only in the cells with the same indexes where matches happen in the previous range
}
return toLook
}
// CountIfs implements the COUNTIFS function.
func CountIfs(args []Result) Result {
errorResult := checkIfsRanges(args, false, "COUNTIFS")
if errorResult.Type != ResultTypeEmpty {
return errorResult
}
match := getIfsMatch(args)
return MakeNumberResult(float64(len(match)))
}
// MaxIfs implements the MAXIFS function.
func MaxIfs(args []Result) Result {
errorResult := checkIfsRanges(args, true, "MAXIFS")
if errorResult.Type != ResultTypeEmpty {
return errorResult
}
match := getIfsMatch(args[1:])
max := -math.MaxFloat64
maxArr := arrayFromRange(args[0])
for _, indexes := range match {
value := maxArr[indexes.rowIndex][indexes.colIndex].ValueNumber
if max < value {
max = value
}
}
if max == -math.MaxFloat64 {
max = 0
}
return MakeNumberResult(float64(max))
}
// MinIfs implements the MINIFS function.
func MinIfs(args []Result) Result {
errorResult := checkIfsRanges(args, true, "MINIFS")
if errorResult.Type != ResultTypeEmpty {
return errorResult
}
match := getIfsMatch(args[1:])
min := math.MaxFloat64
minArr := arrayFromRange(args[0])
for _, indexes := range match {
value := minArr[indexes.rowIndex][indexes.colIndex].ValueNumber
if min > value {
min = value
}
}
if min == math.MaxFloat64 {
min = 0
}
return MakeNumberResult(float64(min))
}
// Min is an implementation of the Excel MIN() function.
func Min(args []Result) Result {
if len(args) == 0 {
@ -231,3 +477,66 @@ func Median(args []Result) Result {
}
return MakeNumberResult(v)
}
func compare(value Result, criteria *criteriaParsed) bool {
t := value.Type
if criteria.isNumber {
return t == ResultTypeNumber && value.ValueNumber == criteria.cNum
} else if t == ResultTypeNumber {
return compareNumberWithRegex(value.ValueNumber, criteria.cRegex)
}
return compareStrings(value, criteria)
}
func compareStrings(valueResult Result, criteria *criteriaParsed) bool {
value := strings.ToLower(valueResult.ValueString) // Excel compares string case-insensitive
regexType := criteria.cRegex.regexType
compareWith := criteria.cRegex.compareWith
if regexType == isEq {
return value == compareWith || wildcard.Match(compareWith, value)
}
if valueResult.Type != ResultTypeEmpty { // the only case when empty result should be taken into account is 'equal' condition like "="&A1 which is handled above, other cases with empty cells (including just A1) should be skipped
if value == criteria.cStr || wildcard.Match(criteria.cStr, value) {
return true
}
if _, err := strconv.ParseFloat(compareWith, 64); err == nil { // criteria should't be the number when compared to string (except 'equal' condition which is handled above)
return false
}
switch regexType {
case isLe:
return value <= compareWith // office apps use the same string comparison as in Golang
case isGe:
return value >= compareWith
case isL:
return value < compareWith
case isG:
return value > compareWith
}
}
return false
}
func compareNumberWithRegex(value float64, cRegex *criteriaRegex) bool {
compareWith, err := strconv.ParseFloat(cRegex.compareWith, 64)
if err != nil {
return false
}
switch cRegex.regexType {
case isEq:
return value == compareWith
case isLe:
return value <= compareWith
case isGe:
return value >= compareWith
case isL:
return value < compareWith
case isG:
return value > compareWith
}
return false
}

View File

@ -10,6 +10,7 @@ package formula
import (
"bytes"
"fmt"
"strconv"
"strings"
"unicode"
)
@ -52,7 +53,7 @@ func init() {
RegisterFunction("_xlfn.UNICHAR", Char) // for now
RegisterFunction("_xlfn.UNICODE", Unicode)
RegisterFunction("UPPER", Upper)
//RegisterFunction("VALUE", )
RegisterFunction("VALUE", Value)
}
// Char is an implementation of the Excel CHAR function that takes an integer in
@ -368,3 +369,24 @@ func Upper(args []Result) Result {
return MakeStringResult(strings.ToUpper(s.ValueString))
}
// Value is an implementation of the Excel VALUE function.
func Value(args []Result) Result {
if len(args) != 1 {
return MakeErrorResult("VALUE requires a single argument")
}
value := args[0]
if value.Type == ResultTypeNumber {
return value
}
if value.Type == ResultTypeString {
result, err := strconv.ParseFloat(value.Value(), 64)
if err == nil {
return MakeNumberResult(result)
}
}
return MakeErrorResult("Incorrect argument for VALUE")
}

View File

@ -0,0 +1,536 @@
// Copyright 2017 FoxyUtils ehf. All rights reserved.
//
// Use of this source code is governed by the terms of the Affero GNU General
// Public License version 3.0 as published by the Free Software Foundation and
// appearing in the file LICENSE included in the packaging of this file. A
// commercial license can be purchased by contacting sales@baliance.com.
package formula_test
import (
"fmt"
"strconv"
"strings"
"testing"
"time"
"github.com/unidoc/unioffice/measurement"
"github.com/unidoc/unioffice/schema/soo/sml"
"github.com/unidoc/unioffice/spreadsheet"
"github.com/unidoc/unioffice/spreadsheet/formula"
)
// Input is an input formula string.
// Expected is the expected output of the formula as a string of format: "value type". It depends on Input and workbook that is being worked with.
type testStruct struct {
Input string
Expected string
}
func runTests(t *testing.T, ctx formula.Context, td []testStruct) {
ev := formula.NewEvaluator()
for _, tc := range td {
t.Run(tc.Input, func(t *testing.T) {
p := formula.Parse(strings.NewReader(tc.Input))
if p == nil {
t.Errorf("error parsing %s", tc.Input)
return
}
result := p.Eval(ctx, ev)
got := fmt.Sprintf("%s %s", result.Value(), result.Type)
if got != tc.Expected {
t.Errorf("expected %s = %s, got %s", tc.Input, tc.Expected, got)
}
})
}
}
func TestCell(t *testing.T) {
td := []testStruct{
{`=CELL("address",A1)`, `$A$1 ResultTypeString`},
{`=CELL("col",B1)`, `2 ResultTypeNumber`},
{`=CELL("row",A1)`, `1 ResultTypeNumber`},
{`=CELL("color",A1)`, `1 ResultTypeNumber`},
{`=CELL("color",A2)`, `0 ResultTypeNumber`},
{`=CELL("contents",A1)`, `-12345.6789 ResultTypeNumber`},
{`=CELL("contents",B1)`, `Hello World ResultTypeString`},
{`=CELL("filename",B1)`, ` ResultTypeString`},
{`=CELL("format",A1)`, `.5- ResultTypeString`},
{`=CELL("format",A2)`, `F0 ResultTypeString`},
{`=CELL("format",A3)`, `.0 ResultTypeString`},
{`=CELL("format",A4)`, `.0() ResultTypeString`},
{`=CELL("format",A5)`, `F2 ResultTypeString`},
{`=CELL("format",A6)`, `.2 ResultTypeString`},
{`=CELL("format",A7)`, `.2 ResultTypeString`},
{`=CELL("format",A8)`, `.2() ResultTypeString`},
{`=CELL("format",A9)`, `P2 ResultTypeString`},
{`=CELL("format",A10)`, `C0 ResultTypeString`},
{`=CELL("format",A11)`, `C2 ResultTypeString`},
{`=CELL("format",A12)`, `C2 ResultTypeString`},
{`=CELL("format",A13)`, `D1 ResultTypeString`},
{`=CELL("format",A14)`, `D1 ResultTypeString`},
{`=CELL("format",A15)`, `D2 ResultTypeString`},
{`=CELL("format",A16)`, `D3 ResultTypeString`},
{`=CELL("format",A17)`, `D4 ResultTypeString`},
{`=CELL("format",A18)`, `D4 ResultTypeString`},
{`=CELL("format",A19)`, `D5 ResultTypeString`},
{`=CELL("format",A20)`, `D6 ResultTypeString`},
{`=CELL("format",A21)`, `D7 ResultTypeString`},
{`=CELL("format",A22)`, `D8 ResultTypeString`},
{`=CELL("format",A23)`, `D9 ResultTypeString`},
{`=CELL("format",A24)`, `S2 ResultTypeString`},
{`=CELL("format",A25)`, `G ResultTypeString`},
{`=CELL("format",C1)`, `.2() ResultTypeString`},
{`=CELL("parentheses",A1)`, `0 ResultTypeNumber`},
{`=CELL("parentheses",C1)`, `1 ResultTypeNumber`},
{`=CELL("prefix",B1)`, ` ResultTypeString`},
{`=CELL("prefix",B2)`, `' ResultTypeString`},
{`=CELL("prefix",B3)`, `" ResultTypeString`},
{`=CELL("prefix",B4)`, `^ ResultTypeString`},
{`=CELL("prefix",B5)`, `\ ResultTypeString`},
{`=CELL("protect",A1)`, `1 ResultTypeNumber`},
{`=CELL("protect",B1)`, `0 ResultTypeNumber`},
{`=CELL("type",A1)`, `v ResultTypeString`},
{`=CELL("type",B1)`, `l ResultTypeString`},
{`=CELL("type",D1)`, `b ResultTypeString`},
{`=CELL("width",A1)`, `15 ResultTypeNumber`},
{`=CELL("width",B1)`, `25 ResultTypeNumber`},
}
ss := spreadsheet.New()
sheet := ss.AddSheet()
// cells with number, needed for testing different formats
for i := 1; i <= 25; i++ {
sheet.Cell("A"+strconv.Itoa(i)).SetNumber(-12345.6789)
}
// cells with string values, needed for testing different alignments
sheet.Cell("B1").SetString("Hello World")
sheet.Cell("B2").SetString("Hello World Left")
sheet.Cell("B3").SetString("Hello World Right")
sheet.Cell("B4").SetString("Hello World Centered")
sheet.Cell("B5").SetString("Hello World Fill")
// for testing "color" function
redStyle := ss.StyleSheet.AddCellStyle()
redStyle.SetNumberFormat("#,##0.00000;[RED]-#,##0.00000")
sheet.Cell("A1").SetStyle(redStyle)
// for testing "parentheses" function
parStyle := ss.StyleSheet.AddCellStyle()
parStyle.SetNumberFormat("#,##0.00_);(#,##0.00)")
sheet.Cell("C1").SetStyle(parStyle)
// for testing "format" function
integerStyle := ss.StyleSheet.AddCellStyle()
integerStyle.SetNumberFormat("00000")
sheet.Cell("A2").SetStyle(integerStyle)
intSepStyle := ss.StyleSheet.AddCellStyle()
intSepStyle.SetNumberFormat("000,000,000")
sheet.Cell("A3").SetStyle(intSepStyle)
intParStyle := ss.StyleSheet.AddCellStyle()
intParStyle.SetNumberFormat("#,##0_);(#,##0)")
sheet.Cell("A4").SetStyle(intParStyle)
financeStyle := ss.StyleSheet.AddCellStyle()
financeStyle.SetNumberFormat("0.00")
sheet.Cell("A5").SetStyle(financeStyle)
decimalStyle := ss.StyleSheet.AddCellStyle()
decimalStyle.SetNumberFormat("#,##0.00")
sheet.Cell("A6").SetStyle(decimalStyle)
decJustStyle := ss.StyleSheet.AddCellStyle()
decJustStyle.SetNumberFormat("_-* #,##0.00_-;-* #,##0.00_-;_-* \"-\"??_-;_-@_-")
sheet.Cell("A7").SetStyle(decJustStyle)
decParStyle := ss.StyleSheet.AddCellStyle()
decParStyle.SetNumberFormat("#,##0.00_);(#,##0.00)")
sheet.Cell("A8").SetStyle(decParStyle)
percentStyle := ss.StyleSheet.AddCellStyle()
percentStyle.SetNumberFormat("0.00%")
sheet.Cell("A9").SetStyle(percentStyle)
intCurStyle := ss.StyleSheet.AddCellStyle()
intCurStyle.SetNumberFormat("[$$-409]#,##0;-[$$-409]#,##0")
sheet.Cell("A10").SetStyle(intCurStyle)
curStyle := ss.StyleSheet.AddCellStyle()
curStyle.SetNumberFormat("[$$-409]#,##0.00;-[$$-409]#,##0.00")
sheet.Cell("A11").SetStyle(curStyle)
curLabelStyle := ss.StyleSheet.AddCellStyle()
curLabelStyle.SetNumberFormat("#,##0.00 [$USD];-#,##0.00 [$USD]")
sheet.Cell("A12").SetStyle(curLabelStyle)
mdyStyle := ss.StyleSheet.AddCellStyle()
mdyStyle.SetNumberFormat("MM/DD/YY")
sheet.Cell("A13").SetStyle(mdyStyle)
dmyStyle := ss.StyleSheet.AddCellStyle()
dmyStyle.SetNumberFormat("D. MMMM YYYY")
sheet.Cell("A14").SetStyle(dmyStyle)
d2Style := ss.StyleSheet.AddCellStyle()
d2Style.SetNumberFormat("MMM DD")
sheet.Cell("A15").SetStyle(d2Style)
d3Style := ss.StyleSheet.AddCellStyle()
d3Style.SetNumberFormat("MM/YY")
sheet.Cell("A16").SetStyle(d3Style)
d4Style := ss.StyleSheet.AddCellStyle()
d4Style.SetNumberFormat("MM/DD/YY\\ HH:MM\\ AM/PM")
sheet.Cell("A17").SetStyle(d4Style)
d4Style = ss.StyleSheet.AddCellStyle()
d4Style.SetNumberFormat("MM/DD/YYYY\\ HH:MM:SS")
sheet.Cell("A18").SetStyle(d4Style)
d5Style := ss.StyleSheet.AddCellStyle()
d5Style.SetNumberFormat("MM\\-DD")
sheet.Cell("A19").SetStyle(d5Style)
d6Style := ss.StyleSheet.AddCellStyle()
d6Style.SetNumberFormat("HH:MM:SS\\ AM/PM")
sheet.Cell("A20").SetStyle(d6Style)
d7Style := ss.StyleSheet.AddCellStyle()
d7Style.SetNumberFormat("HH:MM\\ AM/PM")
sheet.Cell("A21").SetStyle(d7Style)
d8Style := ss.StyleSheet.AddCellStyle()
d8Style.SetNumberFormat("HH:MM:SS")
sheet.Cell("A22").SetStyle(d8Style)
d9Style := ss.StyleSheet.AddCellStyle()
d9Style.SetNumberFormat("HH:MM")
sheet.Cell("A23").SetStyle(d9Style)
sciStyle := ss.StyleSheet.AddCellStyle()
sciStyle.SetNumberFormat("##0.00E+00")
sheet.Cell("A24").SetStyle(sciStyle)
incorrectStyle := ss.StyleSheet.AddCellStyle()
incorrectStyle.SetNumberFormat("incorrect style")
sheet.Cell("A25").SetStyle(incorrectStyle)
// for testing alignments ("prefix" function)
leftStyle := ss.StyleSheet.AddCellStyle()
leftStyle.SetHorizontalAlignment(sml.ST_HorizontalAlignmentLeft)
sheet.Cell("B2").SetStyle(leftStyle)
rightStyle := ss.StyleSheet.AddCellStyle()
rightStyle.SetHorizontalAlignment(sml.ST_HorizontalAlignmentRight)
sheet.Cell("B3").SetStyle(rightStyle)
centerStyle := ss.StyleSheet.AddCellStyle()
centerStyle.SetHorizontalAlignment(sml.ST_HorizontalAlignmentCenter)
sheet.Cell("B4").SetStyle(centerStyle)
fillStyle := ss.StyleSheet.AddCellStyle()
fillStyle.SetHorizontalAlignment(sml.ST_HorizontalAlignmentFill)
sheet.Cell("B5").SetStyle(fillStyle)
ctx := sheet.FormulaContext()
// for testing protected cells
ctx.SetLocked("A1", true)
ctx.SetLocked("B1", false)
// for testing widths
sheet.Column(1).SetWidth(1.5 * measurement.Inch)
sheet.Column(2).SetWidth(2.5 * measurement.Inch)
runTests(t, ctx, td)
}
func TestChoose(t *testing.T) {
td := []testStruct{
{`=CHOOSE(A1,B1,B2,B3)`, `value1 ResultTypeString`},
{`=CHOOSE(A2,B1,B2,B3)`, `value2 ResultTypeString`},
{`=CHOOSE(A3,B1,B2,B3)`, `value3 ResultTypeString`},
{`=CHOOSE(A3,B1,B2)`, `#VALUE! ResultTypeError`},
}
ss := spreadsheet.New()
sheet := ss.AddSheet()
sheet.Cell("A1").SetNumber(1)
sheet.Cell("A2").SetNumber(2)
sheet.Cell("A3").SetNumber(3)
sheet.Cell("B1").SetString("value1")
sheet.Cell("B2").SetString("value2")
sheet.Cell("B3").SetString("value3")
ctx := sheet.FormulaContext()
runTests(t, ctx, td)
}
func TestColumn(t *testing.T) {
td := []testStruct{
{`=COLUMN(A1)`, `1 ResultTypeNumber`},
{`=COLUMN(A2)`, `1 ResultTypeNumber`},
{`=COLUMN(B1)`, `2 ResultTypeNumber`},
}
ss := spreadsheet.New()
sheet := ss.AddSheet()
ctx := sheet.FormulaContext()
runTests(t, ctx, td)
}
func TestColumns(t *testing.T) {
td := []testStruct{
{`=COLUMNS(A1:E8)`, `5 ResultTypeNumber`},
{`=COLUMNS(E8:A1)`, `#VALUE! ResultTypeError`},
}
ss := spreadsheet.New()
sheet := ss.AddSheet()
ctx := sheet.FormulaContext()
runTests(t, ctx, td)
}
func TestCountIf(t *testing.T) {
td := []testStruct{
{`=COUNTIF(B1:B10,A1)`, `2 ResultTypeNumber`},
{`=COUNTIF(B1:B10,A2)`, `3 ResultTypeNumber`},
}
ss := spreadsheet.New()
sheet := ss.AddSheet()
sheet.Cell("A1").SetNumber(1234.4321)
sheet.Cell("A2").SetString("value1")
sheet.Cell("B1").SetString("value1")
sheet.Cell("B2").SetString("value2")
sheet.Cell("B3").SetString("value3")
sheet.Cell("B4").SetNumber(1234.4321)
sheet.Cell("B5").SetString("value1")
sheet.Cell("B6").SetString("value2")
sheet.Cell("B7").SetString("value3")
sheet.Cell("B8").SetString("value1")
sheet.Cell("B9").SetNumber(1234.4322)
sheet.Cell("B10").SetNumber(1234.4321)
ctx := sheet.FormulaContext()
runTests(t, ctx, td)
}
func TestCountIfs(t *testing.T) {
td := []testStruct{
{`=COUNTIFS(A1:E1,">1")`, `1 ResultTypeNumber`},
{`=COUNTIFS(A2:E2,">1")`, `0 ResultTypeNumber`},
{`=COUNTIFS(A3:C4,">1")`, `2 ResultTypeNumber`},
{`=COUNTIFS(A5:C6,"a")`, `2 ResultTypeNumber`},
{`=COUNTIFS(A7:B7,"1",A8:B8,"2")`, `0 ResultTypeNumber`},
{`=COUNTIFS(A9:A10,"1",B9:B10,"2")`, `1 ResultTypeNumber`},
}
ss := spreadsheet.New()
sheet := ss.AddSheet()
sheet.Cell("A1").SetNumber(1)
sheet.Cell("C1").SetNumber(3)
sheet.Cell("D1").SetString("a")
sheet.Cell("E1").SetString("")
sheet.Cell("A2").SetNumber(1)
sheet.Cell("C2").SetNumber(0)
sheet.Cell("D2").SetString("a")
sheet.Cell("E2").SetString("")
sheet.Cell("A3").SetNumber(1)
sheet.Cell("C3").SetNumber(3)
sheet.Cell("A4").SetString("a")
sheet.Cell("B4").SetNumber(4)
sheet.Cell("C4").SetString("c")
sheet.Cell("A5").SetNumber(1)
sheet.Cell("C5").SetString("a")
sheet.Cell("A6").SetString("a")
sheet.Cell("B6").SetNumber(4)
sheet.Cell("C6").SetString("c")
sheet.Cell("A7").SetNumber(1)
sheet.Cell("B8").SetNumber(2)
sheet.Cell("A9").SetNumber(1)
sheet.Cell("B9").SetNumber(2)
sheet.Cell("B10").SetNumber(1)
ctx := sheet.FormulaContext()
runTests(t, ctx, td)
}
func TestSumIf(t *testing.T) {
td := []testStruct{
{`=SUMIF(A1:E1,">2",A3:E3)`, `11100 ResultTypeNumber`},
{`=SUMIF(A2:E2,"*ound",A3:E3)`, `10100 ResultTypeNumber`},
}
ss := spreadsheet.New()
sheet := ss.AddSheet()
sheet.Cell("A1").SetNumber(1)
sheet.Cell("B1").SetNumber(2)
sheet.Cell("C1").SetNumber(3)
sheet.Cell("D1").SetNumber(4)
sheet.Cell("E1").SetNumber(5)
sheet.Cell("A2").SetString("What")
sheet.Cell("B2").SetString("goes")
sheet.Cell("C2").SetString("around")
sheet.Cell("D2").SetString("comes")
sheet.Cell("E2").SetString("around")
sheet.Cell("A3").SetNumber(1)
sheet.Cell("B3").SetNumber(10)
sheet.Cell("C3").SetNumber(100)
sheet.Cell("D3").SetNumber(1000)
sheet.Cell("E3").SetNumber(10000)
ctx := sheet.FormulaContext()
runTests(t, ctx, td)
}
func TestSumIfs(t *testing.T) {
td := []testStruct{
{`=SUMIFS(A3:E3,A1:E1,">2",A2:E2,"*ound")`, `100 ResultTypeNumber`},
{`=SUMIFS(A3:E3,A1:E1,">3",A2:E2,"*ound")`, `0 ResultTypeNumber`},
}
ss := spreadsheet.New()
sheet := ss.AddSheet()
sheet.Cell("A1").SetNumber(5)
sheet.Cell("B1").SetNumber(4)
sheet.Cell("C1").SetNumber(3)
sheet.Cell("D1").SetNumber(2)
sheet.Cell("E1").SetNumber(1)
sheet.Cell("A2").SetString("What")
sheet.Cell("B2").SetString("goes")
sheet.Cell("C2").SetString("around")
sheet.Cell("D2").SetString("comes")
sheet.Cell("E2").SetString("around")
sheet.Cell("A3").SetNumber(1)
sheet.Cell("B3").SetNumber(10)
sheet.Cell("C3").SetNumber(100)
sheet.Cell("D3").SetNumber(1000)
sheet.Cell("E3").SetNumber(10000)
ctx := sheet.FormulaContext()
runTests(t, ctx, td)
}
func TestMinIfs(t *testing.T) {
td := []testStruct{
{`=MINIFS(C1:C5,A1:A5,">2")`, `-1000 ResultTypeNumber`},
{`=MINIFS(C1:C5,B1:B5,"????")`, `-1000 ResultTypeNumber`},
{`=MINIFS(C1:C5,B1:B5,"*ound")`, `10 ResultTypeNumber`},
{`=MINIFS(C1:C5,A1:A5,">3",B1:B5,"????")`, `-1000 ResultTypeNumber`},
{`=MINIFS(C1:C5,A1:A5,">3",B1:B5,"*ound")`, `0 ResultTypeNumber`},
}
ss := spreadsheet.New()
sheet := ss.AddSheet()
sheet.Cell("A1").SetNumber(5)
sheet.Cell("A2").SetNumber(4)
sheet.Cell("A3").SetNumber(3)
sheet.Cell("A4").SetNumber(2)
sheet.Cell("A5").SetNumber(1)
sheet.Cell("B1").SetString("What")
sheet.Cell("B2").SetString("goes")
sheet.Cell("B3").SetString("around")
sheet.Cell("B4").SetString("comes")
sheet.Cell("B5").SetString("around")
sheet.Cell("C1").SetNumber(-1000)
sheet.Cell("C2").SetNumber(-100)
sheet.Cell("C3").SetNumber(10)
sheet.Cell("C4").SetNumber(100)
sheet.Cell("C5").SetNumber(1000)
ctx := sheet.FormulaContext()
runTests(t, ctx, td)
}
func TestMaxIfs(t *testing.T) {
td := []testStruct{
{`=MAXIFS(C1:C5,A1:A5,">2")`, `10 ResultTypeNumber`},
{`=MAXIFS(C1:C5,B1:B5,"????")`, `-100 ResultTypeNumber`},
{`=MAXIFS(C1:C5,B1:B5,"*ound")`, `1000 ResultTypeNumber`},
{`=MAXIFS(C1:C5,A1:A5,">2",B1:B5,"*es")`, `-100 ResultTypeNumber`},
{`=MAXIFS(C1:C5,A1:A5,">3",B1:B5,"*ound")`, `0 ResultTypeNumber`},
}
ss := spreadsheet.New()
sheet := ss.AddSheet()
sheet.Cell("A1").SetNumber(5)
sheet.Cell("A2").SetNumber(4)
sheet.Cell("A3").SetNumber(3)
sheet.Cell("A4").SetNumber(2)
sheet.Cell("A5").SetNumber(1)
sheet.Cell("B1").SetString("What")
sheet.Cell("B2").SetString("goes")
sheet.Cell("B3").SetString("around")
sheet.Cell("B4").SetString("comes")
sheet.Cell("B5").SetString("around")
sheet.Cell("C1").SetNumber(-1000)
sheet.Cell("C2").SetNumber(-100)
sheet.Cell("C3").SetNumber(10)
sheet.Cell("C4").SetNumber(100)
sheet.Cell("C5").SetNumber(1000)
ctx := sheet.FormulaContext()
runTests(t, ctx, td)
}
func TestValue(t *testing.T) {
td := []testStruct{
{`=VALUE(A1)`, `5000 ResultTypeNumber`},
{`=VALUE(A2)`, `4000 ResultTypeNumber`},
{`=VALUE(A1)-VALUE(A2)`, `1000 ResultTypeNumber`},
{`=VALUE(A3)-VALUE(A4)`, `0.25 ResultTypeNumber`},
{`=VALUE(A5)`, `#VALUE! ResultTypeError`},
}
ss := spreadsheet.New()
sheet := ss.AddSheet()
sheet.Cell("A1").SetNumber(5000)
sheet.Cell("A2").SetString("4e+03")
sheet.Cell("A3").SetTime(time.Date(2019, time.November, 4, 16, 0, 0, 0, time.UTC))
sheet.Cell("A4").SetTime(time.Date(2019, time.November, 4, 10, 0, 0, 0, time.UTC))
sheet.Cell("A5").SetString("abcde")
ctx := sheet.FormulaContext()
runTests(t, ctx, td)
}

View File

@ -30,3 +30,33 @@ func (i *ivr) Sheet(name string) Context {
func (i *ivr) SetOffset(col, row uint32) {
}
// GetFormat returns an empty string for the invalid reference context.
func (i *ivr) GetFormat(cellRef string) string {
return ""
}
// GetLabelPrefix returns an empty string for the invalid reference context.
func (i *ivr) GetLabelPrefix(cellRef string) string {
return ""
}
// GetLocked returns FALSE for the invalid reference context.
func (i *ivr) GetLocked(cellRef string) bool {
return false
}
// SetLocked does nothing for the invalid reference context.
func (i *ivr) SetLocked(cellRef string, locked bool) {
}
// GetWidth returns 0 for the invalid reference context.
func (i *ivr) GetWidth(colIdx int) float64 {
return float64(0)
}
// GetFilename returns an empty string for the invalid reference context.
func (i *ivr) GetFilename() string {
return ""
}

View File

@ -12,6 +12,7 @@ import (
"fmt"
"io"
"io/ioutil"
"path/filepath"
"os"
"github.com/unidoc/unioffice"
@ -67,5 +68,11 @@ func Open(filename string) (*Workbook, error) {
if err != nil {
return nil, fmt.Errorf("error opening %s: %s", filename, err)
}
return Read(f, fi.Size())
wb, err := Read(f, fi.Size())
if err != nil {
return nil, err
}
dir, _ := filepath.Abs(filepath.Dir(filename))
wb.filename = filepath.Join(dir, filename)
return wb, nil
}

View File

@ -54,6 +54,7 @@ type Workbook struct {
vmlDrawings []*vmldrawing.Container
charts []*crt.ChartSpace
tables []*sml.Table
filename string
}
// X returns the inner wrapped XML type.
@ -744,3 +745,8 @@ func (wb *Workbook) RemoveCalcChain() {
}
}
}
// GetFilename returns the name of file from which workbook was opened with full path to it
func (wb *Workbook) GetFilename() string {
return wb.filename
}