Skip to content

Commit

Permalink
[IMP] functions: DATEDIF and ADDRESS
Browse files Browse the repository at this point in the history
This commit adds two functions: ADDRESS and DATEDIF.
ADDRESS is used to get the string representation of a cell reference
based on column number and row number.
DATEDIF is used to calculate the time difference between two dates.

task 3201259

closes #2121

Signed-off-by: laa-odoo <[email protected]>
  • Loading branch information
Chenyun Yang committed Mar 15, 2023
1 parent 1633f09 commit bf20db7
Show file tree
Hide file tree
Showing 11 changed files with 460 additions and 2 deletions.
8 changes: 8 additions & 0 deletions demo/data.js
Original file line number Diff line number Diff line change
Expand Up @@ -1356,6 +1356,14 @@ export const demoData = {
B221: { content: '=DAYS360("01/01/2020", "12/31/2020")' },
C221: { content: "360" },
D221: { content: "=IF(B221=C221, 1, 0)" },
A222: { content: "DATEDIF" },
B222: { content: '=DATEDIF("2001/09/15", "2003/06/10", "MD")' },
C222: { content: "26" },
D222: { content: "=IF(B222=C222, 1, 0)" },
A223: { content: "ADDRESS" },
B223: { content: '=ADDRESS(27, 53, 1, TRUE, "sheet!")' },
C223: { content: "'sheet!'!$BA$27" },
D223: { content: "=IF(B223=C223, 1, 0)" },

// DATA
G1: { content: "Name", style: 8 },
Expand Down
31 changes: 31 additions & 0 deletions src/functions/helpers.ts
Original file line number Diff line number Diff line change
Expand Up @@ -21,6 +21,23 @@ const expectNumberValueError = (value: string) =>
value
);

export const expectNumberRangeError = (lowerBound: number, upperBound: number, value: number) =>
_lt(
"The function [[FUNCTION_NAME]] expects a number value between %s and %s inclusive, but receives %s.",
lowerBound.toString(),
upperBound.toString(),
value.toString()
);

export const expectStringSetError = (stringSet: string[], value: string) => {
const stringSetString = stringSet.map((str) => `'${str}'`).join(", ");
return _lt(
"The function [[FUNCTION_NAME]] has an argument with value '%s'. It should be one of: %s.",
value,
stringSetString
);
};

export function toNumber(value: string | number | boolean | null | undefined): number {
switch (typeof value) {
case "number":
Expand Down Expand Up @@ -48,6 +65,20 @@ export function strictToNumber(value: string | number | boolean | null | undefin
return toNumber(value);
}

export function strictToInteger(value: string | number | boolean | null | undefined) {
return Math.trunc(strictToNumber(value));
}

export function assertNumberGreaterThanOrEqualToOne(value: number) {
assert(
() => value >= 1,
_lt(
"The function [[FUNCTION_NAME]] expects a number value to be greater than or equal to 1, but receives %s.",
value.toString()
)
);
}

export function toString(value: string | number | boolean | null | undefined): string {
switch (typeof value) {
case "string":
Expand Down
121 changes: 120 additions & 1 deletion src/functions/module_date.ts
Original file line number Diff line number Diff line change
@@ -1,18 +1,40 @@
import {
addMonthsToDate,
areTwoDatesWithinOneYear,
getDaysInMonth,
getTimeDifferenceInWholeDays,
getTimeDifferenceInWholeMonths,
getTimeDifferenceInWholeYears,
getYearFrac,
INITIAL_1900_DAY,
jsDateToRoundNumber,
MS_PER_DAY,
numberToJsDate,
parseDateTime,
} from "../helpers/dates";
import { _lt } from "../translation";
import { AddFunctionDescription, ArgValue, PrimitiveArgValue } from "../types";
import { arg } from "./arguments";
import { assert, toBoolean, toJsDate, toNumber, toString, visitAny } from "./helpers";
import {
assert,
expectStringSetError,
toBoolean,
toJsDate,
toNumber,
toString,
visitAny,
} from "./helpers";

const DEFAULT_TYPE = 1;
const DEFAULT_WEEKEND = 1;
enum TIME_UNIT {
WHOLE_YEARS = "Y",
WHOLE_MONTHS = "M",
WHOLE_DAYS = "D",
DAYS_WITHOUT_WHOLE_MONTHS = "MD",
MONTH_WITHOUT_WHOLE_YEARS = "YM",
DAYS_BETWEEN_NO_MORE_THAN_ONE_YEAR = "YD",
}

// -----------------------------------------------------------------------------
// DATE
Expand Down Expand Up @@ -59,6 +81,103 @@ export const DATE: AddFunctionDescription = {
isExported: true,
};

// -----------------------------------------------------------------------------
// DATEDIF
// -----------------------------------------------------------------------------
export const DATEDIF: AddFunctionDescription = {
description: _lt("Calculates the number of days, months, or years between two dates."),
args: [
arg(
"start_date (date)",
_lt(
"The start date to consider in the calculation. Must be a reference to a cell containing a DATE, a function returning a DATE type, or a number."
)
),
arg(
"end_date (date)",
_lt(
"The end date to consider in the calculation. Must be a reference to a cell containing a DATE, a function returning a DATE type, or a number."
)
),
arg(
"unit (string)",
_lt(
`A text abbreviation for unit of time. Accepted values are "Y" (the number of whole years between start_date and end_date), "M" (the number of whole months between start_date and end_date), "D" (the number of days between start_date and end_date), "MD" (the number of days between start_date and end_date after subtracting whole months), "YM" (the number of whole months between start_date and end_date after subtracting whole years), "YD" (the number of days between start_date and end_date, assuming start_date and end_date were no more than one year apart).`
)
),
],
returns: ["NUMBER"],
compute: function (
startDate: PrimitiveArgValue,
endDate: PrimitiveArgValue,
unit: PrimitiveArgValue
): number {
const _unit = toString(unit).toUpperCase() as TIME_UNIT;
assert(
() => Object.values(TIME_UNIT).includes(_unit),
expectStringSetError(Object.values(TIME_UNIT), toString(unit))
);
const _startDate = Math.trunc(toNumber(startDate));
const _endDate = Math.trunc(toNumber(endDate));
const jsStartDate = numberToJsDate(_startDate);
const jsEndDate = numberToJsDate(_endDate);
assert(
() => _endDate >= _startDate,
_lt(
"start_date (%s) should be on or before end_date (%s).",
jsStartDate.toLocaleDateString(),
jsEndDate.toLocaleDateString()
)
);
switch (_unit) {
case TIME_UNIT.WHOLE_YEARS:
return getTimeDifferenceInWholeYears(jsStartDate, jsEndDate);
case TIME_UNIT.WHOLE_MONTHS:
return getTimeDifferenceInWholeMonths(jsStartDate, jsEndDate);
case TIME_UNIT.WHOLE_DAYS: {
return getTimeDifferenceInWholeDays(jsStartDate, jsEndDate);
}
case TIME_UNIT.MONTH_WITHOUT_WHOLE_YEARS: {
return (
getTimeDifferenceInWholeMonths(jsStartDate, jsEndDate) -
getTimeDifferenceInWholeYears(jsStartDate, jsEndDate) * 12
);
}
case TIME_UNIT.DAYS_WITHOUT_WHOLE_MONTHS:
// Using "MD" may get incorrect result in Excel
// See: https://support.microsoft.com/en-us/office/datedif-function-25dba1a4-2812-480b-84dd-8b32a451b35c
let days = jsEndDate.getDate() - jsStartDate.getDate();
if (days < 0) {
const monthBeforeEndMonth = new Date(
jsEndDate.getFullYear(),
jsEndDate.getMonth() - 1,
1
);
const daysInMonthBeforeEndMonth = getDaysInMonth(monthBeforeEndMonth);
days = daysInMonthBeforeEndMonth - Math.abs(days);
}
return days;
case TIME_UNIT.DAYS_BETWEEN_NO_MORE_THAN_ONE_YEAR: {
if (areTwoDatesWithinOneYear(_startDate, _endDate)) {
return getTimeDifferenceInWholeDays(jsStartDate, jsEndDate);
}
const endDateWithinOneYear = new Date(
jsStartDate.getFullYear(),
jsEndDate.getMonth(),
jsEndDate.getDate()
);
let days = getTimeDifferenceInWholeDays(jsStartDate, endDateWithinOneYear);
if (days < 0) {
endDateWithinOneYear.setFullYear(jsStartDate.getFullYear() + 1);
days = getTimeDifferenceInWholeDays(jsStartDate, endDateWithinOneYear);
}
return days;
}
}
},
isExported: true,
};

// -----------------------------------------------------------------------------
// DATEVALUE
// -----------------------------------------------------------------------------
Expand Down
73 changes: 72 additions & 1 deletion src/functions/module_lookup.ts
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
import { toZone } from "../helpers/index";
import { getComposerSheetName, toXC, toZone } from "../helpers/index";
import { _lt } from "../translation";
import {
AddFunctionDescription,
Expand All @@ -10,11 +10,14 @@ import { NotAvailableError } from "../types/errors";
import { arg } from "./arguments";
import {
assert,
assertNumberGreaterThanOrEqualToOne,
dichotomicSearch,
expectNumberRangeError,
getNormalizedValueFromColumnRange,
getNormalizedValueFromRowRange,
linearSearch,
normalizeValue,
strictToInteger,
toBoolean,
toNumber,
toString,
Expand All @@ -23,6 +26,7 @@ import {
const DEFAULT_IS_SORTED = true;
const DEFAULT_MATCH_MODE = 0;
const DEFAULT_SEARCH_MODE = 1;
const DEFAULT_ABSOLUTE_RELATIVE_MODE = 1;

function assertAvailable(variable, searchKey) {
if (variable === undefined) {
Expand All @@ -32,6 +36,73 @@ function assertAvailable(variable, searchKey) {
}
}

// -----------------------------------------------------------------------------
// ADDRESS
// -----------------------------------------------------------------------------

export const ADDRESS: AddFunctionDescription = {
description: _lt("Returns a cell reference as a string. "),
args: [
arg("row (number)", _lt("The row number of the cell reference. ")),
arg(
"column (number)",
_lt("The column number (not name) of the cell reference. A is column number 1. ")
),
arg(
`absolute_relative_mode (number, default=${DEFAULT_ABSOLUTE_RELATIVE_MODE})`,
_lt(
"An indicator of whether the reference is row/column absolute. 1 is row and column absolute (e.g. $A$1), 2 is row absolute and column relative (e.g. A$1), 3 is row relative and column absolute (e.g. $A1), and 4 is row and column relative (e.g. A1)."
)
),
arg(
"use_a1_notation (boolean, default=TRUE)",
_lt(
"A boolean indicating whether to use A1 style notation (TRUE) or R1C1 style notation (FALSE)."
)
),
arg(
"sheet (string, optional)",
_lt("A string indicating the name of the sheet into which the address points.")
),
],
returns: ["STRING"],
compute: function (
row: PrimitiveArgValue,
column: PrimitiveArgValue,
absoluteRelativeMode: PrimitiveArgValue = DEFAULT_ABSOLUTE_RELATIVE_MODE,
useA1Notation: PrimitiveArgValue = true,
sheet: PrimitiveArgValue | undefined
): string {
const rowNumber = strictToInteger(row);
const colNumber = strictToInteger(column);
assertNumberGreaterThanOrEqualToOne(rowNumber);
assertNumberGreaterThanOrEqualToOne(colNumber);
const _absoluteRelativeMode = strictToInteger(absoluteRelativeMode);
assert(
() => [1, 2, 3, 4].includes(_absoluteRelativeMode),
expectNumberRangeError(1, 4, _absoluteRelativeMode)
);
const _useA1Notation = toBoolean(useA1Notation);
let cellReference: string;
if (_useA1Notation) {
const rangePart = {
rowFixed: [1, 2].includes(_absoluteRelativeMode) ? true : false,
colFixed: [1, 3].includes(_absoluteRelativeMode) ? true : false,
};
cellReference = toXC(colNumber - 1, rowNumber - 1, rangePart);
} else {
const rowPart = [1, 2].includes(_absoluteRelativeMode) ? `R${rowNumber}` : `R[${rowNumber}]`;
const colPart = [1, 3].includes(_absoluteRelativeMode) ? `C${colNumber}` : `C[${colNumber}]`;
cellReference = rowPart + colPart;
}
if (sheet !== undefined) {
return `${getComposerSheetName(toString(sheet))}!${cellReference}`;
}
return cellReference;
},
isExported: true,
};

// -----------------------------------------------------------------------------
// COLUMN
// -----------------------------------------------------------------------------
Expand Down
38 changes: 38 additions & 0 deletions src/helpers/dates.ts
Original file line number Diff line number Diff line change
Expand Up @@ -369,3 +369,41 @@ export function getYearFrac(startDate: number, endDate: number, _dayCountConvent

return yearsEnd - yearsStart;
}

/**
* Get the number of whole months between two dates.
* e.g.
* 2002/01/01 -> 2002/02/01 = 1 month,
* 2002/01/01 -> 2003/02/01 = 13 months
* @param startDate
* @param endDate
* @returns
*/
export function getTimeDifferenceInWholeMonths(startDate: Date, endDate: Date) {
const months =
(endDate.getFullYear() - startDate.getFullYear()) * 12 +
endDate.getMonth() -
startDate.getMonth();
return startDate.getDate() > endDate.getDate() ? months - 1 : months;
}

export function getTimeDifferenceInWholeDays(startDate: Date, endDate: Date) {
const startUtc = startDate.getTime();
const endUtc = endDate.getTime();
return Math.floor((endUtc - startUtc) / MS_PER_DAY);
}

export function getTimeDifferenceInWholeYears(startDate: Date, endDate: Date) {
const years = endDate.getFullYear() - startDate.getFullYear();
const monthStart = startDate.getMonth();
const monthEnd = endDate.getMonth();
const dateStart = startDate.getDate();
const dateEnd = endDate.getDate();
const isEndMonthDateBigger =
monthEnd > monthStart || (monthEnd === monthStart && dateEnd >= dateStart);
return isEndMonthDateBigger ? years : years - 1;
}

export function areTwoDatesWithinOneYear(startDate: number, endDate: number) {
return getYearFrac(startDate, endDate, 1) < 1;
}
28 changes: 28 additions & 0 deletions tests/__snapshots__/xlsx_export.test.ts.snap
Original file line number Diff line number Diff line change
Expand Up @@ -14055,6 +14055,20 @@ Object {
</f>
</c>
</row>
<row r=\\"166\\" ht=\\"17.25\\" customHeight=\\"1\\" hidden=\\"0\\">
<c r=\\"A166\\" s=\\"1\\">
<f>
ADDRESS(27,53,4,FALSE,\\"sheet!\\")
</f>
</c>
</row>
<row r=\\"167\\" ht=\\"17.25\\" customHeight=\\"1\\" hidden=\\"0\\">
<c r=\\"A167\\" s=\\"1\\">
<f>
DATEDIF(\\"2002-01-01\\",\\"2002-01-02\\",\\"D\\")
</f>
</c>
</row>
</sheetData>
</worksheet>",
"contentType": "sheet",
Expand Down Expand Up @@ -16449,6 +16463,20 @@ Object {
</f>
</c>
</row>
<row r=\\"166\\" ht=\\"17.25\\" customHeight=\\"1\\" hidden=\\"0\\">
<c r=\\"A166\\" s=\\"1\\">
<f>
ADDRESS(27,53,4,FALSE,\\"sheet!\\")
</f>
</c>
</row>
<row r=\\"167\\" ht=\\"17.25\\" customHeight=\\"1\\" hidden=\\"0\\">
<c r=\\"A167\\" s=\\"1\\">
<f>
DATEDIF(\\"2002-01-01\\",\\"2002-01-02\\",\\"D\\")
</f>
</c>
</row>
</sheetData>
</worksheet>",
"contentType": "sheet",
Expand Down
Loading

0 comments on commit bf20db7

Please sign in to comment.