Browse Source

[bug-58468] implement DAYS function

git-svn-id: https://svn.apache.org/repos/asf/poi/trunk@1901361 13f79535-47bb-0310-9956-ffa450edef68
tags/REL_5_2_3
PJ Fanning 2 years ago
parent
commit
e40639a04d

+ 1
- 0
poi/src/main/java/org/apache/poi/ss/formula/atp/AnalysisToolPak.java View File

@@ -98,6 +98,7 @@ public final class AnalysisToolPak implements UDFFinder {
r(m, "CUBEVALUE", null);
r(m, "CUMIPMT", null);
r(m, "CUMPRINC", null);
r(m, "DAYS", Days.instance);
r(m, "DEC2BIN", Dec2Bin.instance);
r(m, "DEC2HEX", Dec2Hex.instance);
r(m, "DEC2OCT", null);

+ 93
- 0
poi/src/main/java/org/apache/poi/ss/formula/functions/Days.java View File

@@ -0,0 +1,93 @@
/* ====================================================================
Licensed to the Apache Software Foundation (ASF) under one or more
contributor license agreements. See the NOTICE file distributed with
this work for additional information regarding copyright ownership.
The ASF licenses this file to You 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 org.apache.poi.ss.formula.functions;

import java.time.LocalDate;
import java.time.temporal.ChronoUnit;
import java.util.Date;

import org.apache.poi.ss.formula.OperationEvaluationContext;
import org.apache.poi.ss.formula.eval.EvaluationException;
import org.apache.poi.ss.formula.eval.NumberEval;
import org.apache.poi.ss.formula.eval.OperandResolver;
import org.apache.poi.ss.formula.eval.ValueEval;
import org.apache.poi.ss.usermodel.DateUtil;
import org.apache.poi.ss.util.DateParser;
import org.apache.poi.util.LocaleUtil;

/**
* <p>Calculates the number of days between two dates based on a real year,
* which is used in some accounting calculations.</p>
*
* <p>
* {@code DAYS(end_date,start_date)}
*
* <ul>
* <li>Start_date, end_date (required):<br/>
* The two dates between which you want to know the number of days.<br/>
* If start_date occurs after end_date, the DAYS function returns a negative number.</li>
*
* </ul>
* </p>
*
* @see <a href="https://support.office.com/en-us/article/DAYS-function-57740535-D549-4395-8728-0F07BFF0B9DF">DAYS function - Microsoft Office</a>
*/
public class Days implements FreeRefFunction {

public static final Days instance = new Days();

private Days() {}

@Override
public ValueEval evaluate(ValueEval[] args, OperationEvaluationContext ec) {
return evaluate(ec.getRowIndex(), ec.getColumnIndex(), args[0], args[1]);
}

private ValueEval evaluate(int srcRowIndex, int srcColumnIndex, ValueEval arg0, ValueEval arg1) {
double result;
try {
LocalDate d0 = getDate(arg0, srcRowIndex, srcColumnIndex);
LocalDate d1 = getDate(arg1, srcRowIndex, srcColumnIndex);
result = evaluate(d0, d1);
} catch (EvaluationException e) {
return e.getErrorEval();
}
return new NumberEval(result);
}

private static double evaluate(LocalDate endDate, LocalDate startDate) {
return ChronoUnit.DAYS.between(startDate, endDate);
}

private static LocalDate getDate(ValueEval eval, int srcRowIndex, int srcColumnIndex) throws EvaluationException {
ValueEval ve = OperandResolver.getSingleValue(eval, srcRowIndex, srcColumnIndex);
try {
double d0 = NumericFunction.singleOperandEvaluate(ve, srcRowIndex, srcColumnIndex);
return getDate(d0);
} catch (Exception e) {
String strText1 = OperandResolver.coerceValueToString(ve);
return DateParser.parseLocalDate(strText1);
}
}

private static LocalDate getDate(double date) {
Date d = DateUtil.getJavaDate(date, false);
return d.toInstant()
.atZone(LocaleUtil.getUserTimeZone().toZoneId())
.toLocalDate();
}
}

+ 69
- 0
poi/src/test/java/org/apache/poi/ss/formula/functions/TestDays.java View File

@@ -0,0 +1,69 @@

/* ====================================================================
Licensed to the Apache Software Foundation (ASF) under one or more
contributor license agreements. See the NOTICE file distributed with
this work for additional information regarding copyright ownership.
The ASF licenses this file to You 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 org.apache.poi.ss.formula.functions;

import org.apache.poi.hssf.usermodel.HSSFCell;
import org.apache.poi.hssf.usermodel.HSSFFormulaEvaluator;
import org.apache.poi.hssf.usermodel.HSSFSheet;
import org.apache.poi.hssf.usermodel.HSSFWorkbook;
import org.apache.poi.ss.usermodel.DateUtil;
import org.apache.poi.ss.usermodel.FormulaError;
import org.junit.jupiter.api.Test;

import java.io.IOException;
import java.time.LocalDate;

import static org.apache.poi.ss.util.Utils.addRow;
import static org.apache.poi.ss.util.Utils.assertDouble;
import static org.apache.poi.ss.util.Utils.assertError;

/**
* Testcase for DAYS() functions
*/
public class TestDays {

//https://support.microsoft.com/en-us/office/days-function-57740535-d549-4395-8728-0f07bff0b9df
@Test
void testMicrosoftExample1() throws IOException {
try (HSSFWorkbook wb = initWorkbook1()) {
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
HSSFCell cell = wb.getSheetAt(0).getRow(0).createCell(12);
assertDouble(fe, cell, "DAYS(\"15-MAR-2021\",\"1-FEB-2021\")", 42, 0.00000000001);
assertDouble(fe, cell, "DAYS(A2,A3)", 364, 0.00000000001);
}
}

@Test
void testInvalid() throws IOException {
try (HSSFWorkbook wb = initWorkbook1()) {
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
HSSFCell cell = wb.getSheetAt(0).getRow(0).createCell(12);
assertError(fe, cell, "DAYS(\"15-XYZ\",\"1-FEB-2021\")", FormulaError.VALUE);
assertError(fe, cell, "DAYS(\"15-MAR-2021\",\"1-XYZ\")", FormulaError.VALUE);
}
}

private HSSFWorkbook initWorkbook1() {
HSSFWorkbook wb = new HSSFWorkbook();
HSSFSheet sheet = wb.createSheet();
addRow(sheet, 0, "Data");
addRow(sheet, 1, DateUtil.getExcelDate(LocalDate.parse("2021-12-31")));
addRow(sheet, 2, DateUtil.getExcelDate(LocalDate.parse("2021-01-01")));
return wb;
}
}

Loading…
Cancel
Save