From bf20db7f3577a4c096b2a9158683bf8c0c701c4b Mon Sep 17 00:00:00 2001 From: Chenyun Yang Date: Tue, 28 Feb 2023 12:43:52 +0000 Subject: [PATCH] [IMP] functions: DATEDIF and ADDRESS 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 odoo/o-spreadsheet#2121 Signed-off-by: laa-odoo --- demo/data.js | 8 ++ src/functions/helpers.ts | 31 +++++ src/functions/module_date.ts | 121 +++++++++++++++++- src/functions/module_lookup.ts | 73 ++++++++++- src/helpers/dates.ts | 38 ++++++ tests/__snapshots__/xlsx_export.test.ts.snap | 28 ++++ .../xlsx_demo_data/xl/sharedStrings.xml | 6 + .../xlsx_demo_data/xl/worksheets/sheet2.xml | 32 +++++ tests/functions/module_date.test.ts | 54 ++++++++ tests/functions/module_lookup.test.ts | 69 ++++++++++ tests/xlsx_export.test.ts | 2 + 11 files changed, 460 insertions(+), 2 deletions(-) diff --git a/demo/data.js b/demo/data.js index becad28fbd..fb0d776ad9 100644 --- a/demo/data.js +++ b/demo/data.js @@ -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 }, diff --git a/src/functions/helpers.ts b/src/functions/helpers.ts index 82b70a2876..9f0a56c3a1 100644 --- a/src/functions/helpers.ts +++ b/src/functions/helpers.ts @@ -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": @@ -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": diff --git a/src/functions/module_date.ts b/src/functions/module_date.ts index f9969eef63..f634322ad8 100644 --- a/src/functions/module_date.ts +++ b/src/functions/module_date.ts @@ -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 @@ -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 // ----------------------------------------------------------------------------- diff --git a/src/functions/module_lookup.ts b/src/functions/module_lookup.ts index f46158f6b0..cbd42bd7f2 100644 --- a/src/functions/module_lookup.ts +++ b/src/functions/module_lookup.ts @@ -1,4 +1,4 @@ -import { toZone } from "../helpers/index"; +import { getComposerSheetName, toXC, toZone } from "../helpers/index"; import { _lt } from "../translation"; import { AddFunctionDescription, @@ -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, @@ -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) { @@ -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 // ----------------------------------------------------------------------------- diff --git a/src/helpers/dates.ts b/src/helpers/dates.ts index c5652cfee2..63e549bef6 100644 --- a/src/helpers/dates.ts +++ b/src/helpers/dates.ts @@ -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; +} diff --git a/tests/__snapshots__/xlsx_export.test.ts.snap b/tests/__snapshots__/xlsx_export.test.ts.snap index a8f236f44f..0fa8de4600 100644 --- a/tests/__snapshots__/xlsx_export.test.ts.snap +++ b/tests/__snapshots__/xlsx_export.test.ts.snap @@ -14055,6 +14055,20 @@ Object { + + ", "contentType": "sheet", @@ -16449,6 +16463,20 @@ Object { + + ", "contentType": "sheet", diff --git a/tests/__xlsx__/xlsx_demo_data/xl/sharedStrings.xml b/tests/__xlsx__/xlsx_demo_data/xl/sharedStrings.xml index b349fa7873..908b48f389 100644 --- a/tests/__xlsx__/xlsx_demo_data/xl/sharedStrings.xml +++ b/tests/__xlsx__/xlsx_demo_data/xl/sharedStrings.xml @@ -1231,4 +1231,10 @@ NotHidden + + ADDRESS + + + DATEDIF + diff --git a/tests/__xlsx__/xlsx_demo_data/xl/worksheets/sheet2.xml b/tests/__xlsx__/xlsx_demo_data/xl/worksheets/sheet2.xml index 43ea3e4d7b..db99af99d5 100644 --- a/tests/__xlsx__/xlsx_demo_data/xl/worksheets/sheet2.xml +++ b/tests/__xlsx__/xlsx_demo_data/xl/worksheets/sheet2.xml @@ -2839,6 +2839,38 @@ 1 + + + 410 + + + ADDRESS(1,1,4,FALSE,"sheet!") + 'sheet!'!R[1]C[1] + + + 'sheet!'!R[1]C[1] + + + + 1 + + + + + 411 + + + DATEDIF("2002/01/01","2002/01/02","D") + 1 + + + 1 + + + + 1 + + diff --git a/tests/functions/module_date.test.ts b/tests/functions/module_date.test.ts index a5b7bb2126..700a7eb853 100644 --- a/tests/functions/module_date.test.ts +++ b/tests/functions/module_date.test.ts @@ -93,6 +93,60 @@ describe("DATE formula", () => { }); }); +describe("DATEDIF formula", () => { + test("takes 3 arguments", () => { + // @compatibility: on google sheets, all return #N/A + expect(evaluateCell("A1", { A1: "=DATEDIF()" })).toBe("#BAD_EXPR"); + expect(evaluateCell("A1", { A1: '=DATEDIF("2001/01/01")' })).toBe("#BAD_EXPR"); + expect(evaluateCell("A1", { A1: '=DATEDIF("2001/01/01","2001/01/02")' })).toBe("#BAD_EXPR"); + }); + + test("the first two arguments can be functions returning a DATE, or numbers", () => { + expect(evaluateCell("A1", { A1: '=DATEDIF("2001/01/01","2001/01/02","D")' })).toBe(1); + expect(evaluateCell("A1", { A1: '=DATEDIF("2001-01-01","2001-01-02","D")' })).toBe(1); + expect( + evaluateCell("A1", { A1: '=DATEDIF("2001/01/01 23:10:30","2001/01/02 02:09:31","D")' }) + ).toBe(1); + expect(evaluateCell("A1", { A1: '=DATEDIF(Date(2001,1,1),"2001/01/02","D")' })).toBe(1); + expect(evaluateCell("A1", { A1: '=DATEDIF("2001/01/01",Date(2001,1,2),"D")' })).toBe(1); + expect(evaluateCell("A1", { A1: '=DATEDIF(1,2,"D")' })).toBe(1); + expect(evaluateCell("A1", { A1: '=DATEDIF(1.1,1.2,"D")' })).toBe(0); + expect(evaluateCell("A1", { A1: '=DATEDIF(FALSE,TRUE,"D")' })).toBe(1); + }); + + test("the first two arguments can be references to cells with DATE", () => { + expect( + evaluateCell("A3", { + A1: "=DATE(2002,1,1)", + A2: "=DATE(2002,1,2)", + A3: '=DATEDIF(A1,A2,"D")', + }) + ).toBe(1); + }); + + test("invalid first two arguments", () => { + expect(evaluateCell("A1", { A1: '=DATEDIF("ABC","CDE","D")' })).toBe("#ERROR"); // @compatibility: on google sheets, all return #VALUE + }); + + test("start_date has to be on or before end_date", () => { + expect(evaluateCell("A1", { A1: '=DATEDIF("2001/01/01","2000/12/31","D")' })).toBe("#ERROR"); // @compatibility: on google sheets, return #NUM + }); + + test("unit has to be one of the pre-defined units", () => { + expect(evaluateCell("A1", { A1: '=DATEDIF("2001/01/01","2001/01/02",123)' })).toBe("#ERROR"); // @compatibility: on google sheets, return #NUM + expect(evaluateCell("A1", { A1: '=DATEDIF("2001/01/01","2001/01/02","ABC")' })).toBe("#ERROR"); // @compatibility: on google sheets, return #NUM + }); + + test("functional tests on units", () => { + expect(evaluateCell("A1", { A1: '=DATEDIF("2001/09/15","2003/06/10","D")' })).toBe(633); + expect(evaluateCell("A1", { A1: '=DATEDIF("2001/09/15","2003/06/10","M")' })).toBe(20); + expect(evaluateCell("A1", { A1: '=DATEDIF("2001/09/15","2003/06/10","Y")' })).toBe(1); + expect(evaluateCell("A1", { A1: '=DATEDIF("2001/09/15","2003/06/10","YM")' })).toBe(8); + expect(evaluateCell("A1", { A1: '=DATEDIF("2001/09/15","2003/06/10","MD")' })).toBe(26); + expect(evaluateCell("A1", { A1: '=DATEDIF("2001/09/15","2003/06/10","YD")' })).toBe(268); + }); +}); + describe("DATEVALUE formula", () => { test("functional tests on simple arguments", () => { expect(evaluateCell("A1", { A1: "=DATEVALUE(40931)" })).toBe("#ERROR"); // @compatibility, retrun #VALUE! on Google Sheet diff --git a/tests/functions/module_lookup.test.ts b/tests/functions/module_lookup.test.ts index f945cd5454..270ef931a0 100644 --- a/tests/functions/module_lookup.test.ts +++ b/tests/functions/module_lookup.test.ts @@ -2,6 +2,75 @@ import { Model } from "../../src/model"; import { setCellContent } from "../test_helpers/commands_helpers"; import { evaluateCell, evaluateGrid } from "../test_helpers/helpers"; +describe("ADDRESS formula", () => { + test("functional tests without argument", () => { + expect(evaluateCell("A1", { A1: "=ADDRESS()" })).toBe("#BAD_EXPR"); // @compatibility: on google sheets, return #N/A + expect(evaluateCell("A1", { A1: "=ADDRESS(,)" })).toBe("#ERROR"); // @compatibility: on google sheets, return #VALUE + }); + + test("functional test with negative arguments or zero", () => { + // @compatibility: on google sheets, all return #VALUE + expect(evaluateCell("A1", { A1: "=ADDRESS(1,0)" })).toBe("#ERROR"); + expect(evaluateCell("A1", { A1: "=ADDRESS(0,1)" })).toBe("#ERROR"); + expect(evaluateCell("A1", { A1: "=ADDRESS(-1,1)" })).toBe("#ERROR"); + expect(evaluateCell("A1", { A1: "=ADDRESS(1,-1)" })).toBe("#ERROR"); + expect(evaluateCell("A1", { A1: "=ADDRESS(-1,-1)" })).toBe("#ERROR"); + expect(evaluateCell("A1", { A1: "=ADDRESS(0,0)" })).toBe("#ERROR"); + }); + + test("functional test with positive numbers or strings that can be parsed into positive numbers", () => { + expect(evaluateCell("A1", { A1: "=ADDRESS(1,4)" })).toBe("$D$1"); + expect(evaluateCell("A1", { A1: '=ADDRESS("2",1)' })).toBe("$A$2"); + expect(evaluateCell("A1", { A1: '=ADDRESS(3,"5")' })).toBe("$E$3"); + expect(evaluateCell("A1", { A1: '=ADDRESS("27","53")' })).toBe("$BA$27"); + }); + + test("functional test with strings that cannot be parsed into positive numbers", () => { + expect(evaluateCell("A1", { A1: '=ADDRESS("row",4)' })).toBe("#ERROR"); + expect(evaluateCell("A1", { A1: '=ADDRESS("row","col")' })).toBe("#ERROR"); + expect(evaluateCell("A1", { A1: '=ADDRESS(3,"col")' })).toBe("#ERROR"); + }); + + test("functional tests on valid absolute/relative modes (1-4)", () => { + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53)" })).toBe("$BA$27"); + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,1)" })).toBe("$BA$27"); + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,2)" })).toBe("BA$27"); + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,3)" })).toBe("$BA27"); + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,4)" })).toBe("BA27"); + }); + + test("functional tests on invalid absolute/relative modes", () => { + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,5)" })).toBe("#ERROR"); // @compatibility: on google sheets, return #NUM + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,0)" })).toBe("#ERROR"); // @compatibility: on google sheets, return #NUM + expect(evaluateCell("A1", { A1: '=ADDRESS(27,53,"string")' })).toBe("#ERROR"); // @compatibility: on google sheets, return #VALUE + }); + + test("functional tests on using A1 notation or R1C1 notation", () => { + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,,)" })).toBe("$BA$27"); + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,,true)" })).toBe("$BA$27"); + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,,false)" })).toBe("R27C53"); + expect(evaluateCell("A1", { A1: '=ADDRESS(27,53,,"TRUE")' })).toBe("$BA$27"); + expect(evaluateCell("A1", { A1: '=ADDRESS(27,53,,"FALSE")' })).toBe("R27C53"); + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,,1)" })).toBe("$BA$27"); + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,,0)" })).toBe("R27C53"); + expect(evaluateCell("A1", { A1: '=ADDRESS(27,53,,"")' })).toBe("R27C53"); + expect(evaluateCell("A1", { A1: '=ADDRESS(27,53,," ")' })).toBe("#ERROR"); // @compatibility: on google sheets, return #VALUE + }); + + test("functional tests on using R1C1 notation and different absolute/relative modes", () => { + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,1,false)" })).toBe("R27C53"); + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,2,false)" })).toBe("R27C[53]"); + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,3,false)" })).toBe("R[27]C53"); + expect(evaluateCell("A1", { A1: "=ADDRESS(27,53,4,false)" })).toBe("R[27]C[53]"); + }); + + test("functional tests on sheet name", () => { + expect(evaluateCell("A1", { A1: '=ADDRESS(27,53,,,"sheet")' })).toBe("sheet!$BA$27"); + expect(evaluateCell("A1", { A1: '=ADDRESS(27,53,,,"sheet!")' })).toBe("'sheet!'!$BA$27"); + expect(evaluateCell("A1", { A1: '=ADDRESS(27,53,,,"")' })).toBe("''!$BA$27"); + }); +}); + describe("COLUMN formula", () => { test("functional tests without argument", () => { expect(evaluateCell("A1", { A1: "=COLUMN()" })).toBe(1); diff --git a/tests/xlsx_export.test.ts b/tests/xlsx_export.test.ts index b447e4e05b..ec25cdcd1c 100644 --- a/tests/xlsx_export.test.ts +++ b/tests/xlsx_export.test.ts @@ -286,6 +286,8 @@ const allExportableFormulasData = { A163: { content: "=ISNA(A162)" }, A164: { content: "=ISERR(A162)" }, A165: { content: '=HYPERLINK("https://www.odoo.com", "Odoo")' }, + A166: { content: '=ADDRESS(27,53,4,FALSE,"sheet!")' }, + A167: { content: '=DATEDIF("2002/01/01","2002/01/02","D")' }, // DATA G1: { content: "Name", style: 8 },