From a8f31d7651b0787b24059a8d3deccd19a4505f3b Mon Sep 17 00:00:00 2001 From: Igor Zotov Date: Mon, 31 Oct 2022 11:42:41 +0300 Subject: [PATCH 1/5] [se] Choosecols --- .../lookupandreferenceFunctions.js | 77 +++++++++++++++++-- cell/model/FormulaObjects/parserFormula.js | 11 +++ 2 files changed, 80 insertions(+), 8 deletions(-) diff --git a/cell/model/FormulaObjects/lookupandreferenceFunctions.js b/cell/model/FormulaObjects/lookupandreferenceFunctions.js index eb75c051d7..d1f23aab35 100644 --- a/cell/model/FormulaObjects/lookupandreferenceFunctions.js +++ b/cell/model/FormulaObjects/lookupandreferenceFunctions.js @@ -67,7 +67,7 @@ function (window, undefined) { var _func = AscCommonExcel._func; cFormulaFunctionGroup['LookupAndReference'] = cFormulaFunctionGroup['LookupAndReference'] || []; - cFormulaFunctionGroup['LookupAndReference'].push(cADDRESS, cAREAS, cCHOOSE, cCOLUMN, cCOLUMNS, cFORMULATEXT, + cFormulaFunctionGroup['LookupAndReference'].push(cADDRESS, cAREAS, cCHOOSE, cCHOOSECOLS, cCOLUMN, cCOLUMNS, cFORMULATEXT, cGETPIVOTDATA, cHLOOKUP, cHYPERLINK, cINDEX, cINDIRECT, cLOOKUP, cMATCH, cOFFSET, cROW, cROWS, cRTD, cTRANSPOSE, cUNIQUE, cVLOOKUP, cXLOOKUP, cVSTACK, cHSTACK, cTOROW, cTOCOL, cWRAPROWS, cWRAPCOLS); @@ -281,6 +281,67 @@ function (window, undefined) { return new cError(cErrorType.wrong_value_type); }; + /** + * @constructor + * @extends {AscCommonExcel.cBaseFunction} + */ + function cCHOOSECOLS() { + } + + //***array-formula*** + cCHOOSECOLS.prototype = Object.create(cBaseFunction.prototype); + cCHOOSECOLS.prototype.constructor = cCHOOSECOLS; + cCHOOSECOLS.prototype.name = 'CHOOSECOLS'; + cCHOOSECOLS.prototype.argumentsMin = 2; + cCHOOSECOLS.prototype.argumentsMax = 32; + cCHOOSECOLS.prototype.argumentsType = [argType.reference, [argType.number]]; + cCHOOSECOLS.prototype.Calculate = function (arg) { + var argError = cBaseFunction.prototype._checkErrorArg.call(this, arg); + if (argError) { + return argError; + } + + let arg1 = arg[0]; + let matrix; + if (arg1.type === cElementType.cellsRange || arg1.type === cElementType.array || arg1.type === cElementType.cell || arg1.type === cElementType.cell3D) { + matrix = arg1.getMatrix(); + } else if (arg1.type === cElementType.cellsRange3D) { + if (arg1.isSingleSheet()) { + matrix = arg1.getMatrix()[0]; + } else { + return new cError(cErrorType.bad_reference); + } + } else if (arg1.type === cElementType.error) { + return arg1; + } else if (arg1.type === cElementType.empty) { + return new cError(cErrorType.wrong_value_type); + } else { + matrix = [[arg1]]; + } + + var dimension = arg1.getDimensions(); + let res; + for (let i = 1; i < arg.length; i++) { + let _arg = arg[i]; + _arg = _arg.tocNumber(); + if (arg1.type === cElementType.error) { + return arg1; + } + _arg = _arg.tocNumber(); + if (_arg < 1 && _arg > dimension.col) { + return new cError(cErrorType.wrong_value_type); + } + + if (!res) { + res = new cArray(); + } + + res.pushCol(matrix, _arg); + } + + return res ? res : new cError(cErrorType.wrong_value_type); + }; + /** * @constructor * @extends {AscCommonExcel.cBaseFunction} @@ -2502,7 +2563,7 @@ function (window, undefined) { } else { return new cError(cErrorType.wrong_value_type); } - } + }; /** * @constructor @@ -2544,7 +2605,7 @@ function (window, undefined) { let maxColCount = 0; for (let j = 0; j < matrix.length; j++) { if (matrix[j]) { - maxColCount = Math.max(maxColCount, matrix[j].length) + maxColCount = Math.max(maxColCount, matrix[j].length); for (let k = 0; k < matrix[j].length; k++) { if (matrix[j][k]) { if (!unionArray) { @@ -2569,7 +2630,7 @@ function (window, undefined) { } else { return new cError(cErrorType.wrong_value_type); } - } + }; function toRowCol(arg, argument1, toCol) { var argError = cBaseFunction.prototype._checkErrorArg.call(this, arg); @@ -2680,7 +2741,7 @@ function (window, undefined) { cTOROW.prototype.isXLFN = true; cTOROW.prototype.Calculate = function (arg) { return toRowCol(arg, arguments[1]); - } + }; /** * @constructor @@ -2701,7 +2762,7 @@ function (window, undefined) { cTOCOL.prototype.isXLFN = true; cTOCOL.prototype.Calculate = function (arg) { return toRowCol(arg, arguments[1], true); - } + }; function wrapRowsCols(arg, argument1, toCol) { var argError = cBaseFunction.prototype._checkErrorArg.call(this, arg); @@ -2799,7 +2860,7 @@ function (window, undefined) { cWRAPROWS.prototype.isXLFN = true; cWRAPROWS.prototype.Calculate = function (arg) { return wrapRowsCols(arg, arguments[1]); - } + }; /** * @constructor @@ -2820,7 +2881,7 @@ function (window, undefined) { cWRAPCOLS.prototype.isXLFN = true; cWRAPCOLS.prototype.Calculate = function (arg) { return wrapRowsCols(arg, arguments[1], true); - } + }; var g_oVLOOKUPCache = new VHLOOKUPCache(false); var g_oHLOOKUPCache = new VHLOOKUPCache(true); diff --git a/cell/model/FormulaObjects/parserFormula.js b/cell/model/FormulaObjects/parserFormula.js index 1b99706bc7..70fb30d98b 100644 --- a/cell/model/FormulaObjects/parserFormula.js +++ b/cell/model/FormulaObjects/parserFormula.js @@ -2711,6 +2711,17 @@ parserHelp.setDigitSeparator(AscCommon.g_oDefaultCultureInfo.NumberDecimalSepara this.countElement += this.array[i].length; } }; + cArray.prototype.pushCol = function (matrix, colNum) { + for (let i = 0; i < matrix.length; i++) { + if (matrix[i] && matrix[i][colNum]) { + if (!this.array[i]) { + this.array[i] = []; + } + this.array[i].push(matrix[i][colNum]); + } + } + this.recalculate(); + }; /** From 4a0e090c030e1e822ba2d0e766bc9b578320bad6 Mon Sep 17 00:00:00 2001 From: Igor Zotov Date: Mon, 31 Oct 2022 12:58:07 +0300 Subject: [PATCH 2/5] [se] By tests --- .../lookupandreferenceFunctions.js | 19 +- .../spreadsheet-calculation/FormulaTests.js | 188 ++++++++++++++++++ 2 files changed, 203 insertions(+), 4 deletions(-) diff --git a/cell/model/FormulaObjects/lookupandreferenceFunctions.js b/cell/model/FormulaObjects/lookupandreferenceFunctions.js index d1f23aab35..955cd55388 100644 --- a/cell/model/FormulaObjects/lookupandreferenceFunctions.js +++ b/cell/model/FormulaObjects/lookupandreferenceFunctions.js @@ -293,8 +293,9 @@ function (window, undefined) { cCHOOSECOLS.prototype.constructor = cCHOOSECOLS; cCHOOSECOLS.prototype.name = 'CHOOSECOLS'; cCHOOSECOLS.prototype.argumentsMin = 2; - cCHOOSECOLS.prototype.argumentsMax = 32; + cCHOOSECOLS.prototype.argumentsMax = 253; cCHOOSECOLS.prototype.argumentsType = [argType.reference, [argType.number]]; + cCHOOSECOLS.prototype.returnValueType = AscCommonExcel.cReturnFormulaType.array; cCHOOSECOLS.prototype.Calculate = function (arg) { var argError = cBaseFunction.prototype._checkErrorArg.call(this, arg); if (argError) { @@ -323,12 +324,22 @@ function (window, undefined) { let res; for (let i = 1; i < arg.length; i++) { let _arg = arg[i]; + + if (cElementType.cellsRange === _arg.type || cElementType.cellsRange3D === _arg.type) { + _arg = _arg.getValue2(0,0); + } else if (cElementType.array === _arg.type) { + _arg = _arg.getElementRowCol(0, 0); + } + _arg = _arg.tocNumber(); if (arg1.type === cElementType.error) { return arg1; } - _arg = _arg.tocNumber(); - if (_arg < 1 && _arg > dimension.col) { + _arg = _arg.toNumber(); + let reverse = _arg < 0; + _arg = Math.abs(_arg); + _arg = parseInt(_arg); + if (_arg < 1 || _arg > dimension.col) { return new cError(cErrorType.wrong_value_type); } @@ -336,7 +347,7 @@ function (window, undefined) { res = new cArray(); } - res.pushCol(matrix, _arg); + res.pushCol(matrix, reverse ? dimension.col - (_arg - 1) - 1 : _arg - 1); } return res ? res : new cError(cErrorType.wrong_value_type); diff --git a/tests/cell/spreadsheet-calculation/FormulaTests.js b/tests/cell/spreadsheet-calculation/FormulaTests.js index 42bab04844..11d105a228 100644 --- a/tests/cell/spreadsheet-calculation/FormulaTests.js +++ b/tests/cell/spreadsheet-calculation/FormulaTests.js @@ -2372,6 +2372,194 @@ $(function () { //testArrayFormula2(assert, "CHOOSE", 2, 9); }); + QUnit.test("Test: \"CHOOSECOLS\"", function (assert) { + //1. добавляем общие тесты + + ws.getRange2("A1").setValue("1"); + ws.getRange2("A2").setValue("2"); + ws.getRange2("A3").setValue(""); + ws.getRange2("A4").setValue("4"); + ws.getRange2("A5").setValue("#N/A"); + ws.getRange2("A6").setValue("f"); + + ws.getRange2("B1").setValue("q"); + ws.getRange2("B2").setValue("w"); + ws.getRange2("B3").setValue("e"); + ws.getRange2("B4").setValue("test"); + ws.getRange2("B5").setValue("hhh"); + ws.getRange2("B6").setValue("g"); + + ws.getRange2("C1").setValue("r"); + ws.getRange2("C2").setValue("3"); + ws.getRange2("C3").setValue("5"); + ws.getRange2("C4").setValue(""); + ws.getRange2("C5").setValue("6"); + ws.getRange2("C6").setValue("h"); + + + oParser = new parserFormula("CHOOSECOLS(A1:C6;-1;1)", "A1", ws); + assert.ok(oParser.parse()); + let array = oParser.calculate(); + + assert.strictEqual(array.getElementRowCol(0, 0).getValue(), 'r'); + assert.strictEqual(array.getElementRowCol(1, 0).getValue(), 3); + assert.strictEqual(array.getElementRowCol(2, 0).getValue(), 5); + assert.strictEqual(array.getElementRowCol(3, 0).getValue(), ''); + assert.strictEqual(array.getElementRowCol(4, 0).getValue(), 6); + assert.strictEqual(array.getElementRowCol(5, 0).getValue(), 'h'); + + assert.strictEqual(array.getElementRowCol(0, 1).getValue(), 1); + assert.strictEqual(array.getElementRowCol(1, 1).getValue(), 2); + assert.strictEqual(array.getElementRowCol(2, 1).getValue(), ''); + assert.strictEqual(array.getElementRowCol(3, 1).getValue(), 4); + assert.strictEqual(array.getElementRowCol(4, 1).getValue(), '#N/A'); + assert.strictEqual(array.getElementRowCol(5, 1).getValue(), 'f'); + + + oParser = new parserFormula("CHOOSECOLS(A1:C6;-2;3)", "A1", ws); + assert.ok(oParser.parse()); + array = oParser.calculate(); + + assert.strictEqual(array.getElementRowCol(0, 0).getValue(), 'q'); + assert.strictEqual(array.getElementRowCol(1, 0).getValue(), 'w'); + assert.strictEqual(array.getElementRowCol(2, 0).getValue(), 'e'); + assert.strictEqual(array.getElementRowCol(3, 0).getValue(), 'test'); + assert.strictEqual(array.getElementRowCol(4, 0).getValue(), 'hhh'); + assert.strictEqual(array.getElementRowCol(5, 0).getValue(), 'g'); + + assert.strictEqual(array.getElementRowCol(0, 1).getValue(), 'r'); + assert.strictEqual(array.getElementRowCol(1, 1).getValue(), 3); + assert.strictEqual(array.getElementRowCol(2, 1).getValue(), 5); + assert.strictEqual(array.getElementRowCol(3, 1).getValue(), ''); + assert.strictEqual(array.getElementRowCol(4, 1).getValue(), 6); + assert.strictEqual(array.getElementRowCol(5, 1).getValue(), 'h'); + + + oParser = new parserFormula("CHOOSECOLS(A1:C6;-4;3)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + + oParser = new parserFormula("CHOOSECOLS(A1:C6;-2;4)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + + oParser = new parserFormula("CHOOSECOLS(A1:C6;-2;0)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + + + //2. аргументы - разные типы. нужно пербрать все аргументы + //2.1 аргумент - number + oParser = new parserFormula("WRAPCOLS(1,3)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + //2.2 аргумент - string + oParser = new parserFormula("WRAPCOLS(\"test\",3)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), "test"); + //2.3 аргумент - bool + oParser = new parserFormula("WRAPCOLS(true,3)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), "TRUE"); + //2.4 аргумент - error + oParser = new parserFormula("WRAPCOLS(#VALUE!,3)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + //2.5 аргумент - empty + oParser = new parserFormula("WRAPCOLS(,2)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + //2.6 аргумент - cellsRange + //2.7 аргумент - cell + oParser = new parserFormula("WRAPCOLS(B1, 10)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), "test2"); + + //2.8 аргумент - array + oParser = new parserFormula("WRAPCOLS({2;\"\";\"test\"},2)", "A1", ws); + assert.ok(oParser.parse()); + array = oParser.calculate(); + + assert.strictEqual(array.getElementRowCol(0, 0).getValue(), 2); + assert.strictEqual(array.getElementRowCol(1, 0).getValue(), ''); + assert.strictEqual(array.getElementRowCol(0, 1).getValue(), 'test'); + assert.strictEqual(array.getElementRowCol(1, 1).getValue(), '#N/A'); + + + //2.2 аргумент - string + oParser = new parserFormula("WRAPCOLS(1,\"test\")", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + //2.3 аргумент - bool + oParser = new parserFormula("WRAPCOLS(1,true)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + //2.4 аргумент - error + oParser = new parserFormula("WRAPCOLS(1, #VALUE!)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + //2.5 аргумент - empty + oParser = new parserFormula("WRAPCOLS(1,)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#NUM!"); + + + //2.6 аргумент - cellsRange + //2.7 аргумент - cell + oParser = new parserFormula("WRAPCOLS(1,A1)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + + oParser = new parserFormula("WRAPCOLS(1,A1:B5)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + + //2.8 аргумент - array + oParser = new parserFormula("WRAPCOLS(1,{2;\"\";\"test\"})", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + + + //2. аргументы - разные типы. нужно пербрать все аргументы + //2.1 аргумент - number + oParser = new parserFormula("WRAPCOLS(1,3,1)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + + + //2.2 аргумент - string + oParser = new parserFormula("WRAPCOLS(1,3,\"test\")", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + //2.3 аргумент - bool + oParser = new parserFormula("WRAPCOLS(1,3,true)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + //2.4 аргумент - error + oParser = new parserFormula("WRAPCOLS(1,3,#VALUE!)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + //2.5 аргумент - empty + oParser = new parserFormula("WRAPCOLS(1,3,)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + //2.6 аргумент - cellsRange + //2.7 аргумент - cell + oParser = new parserFormula("WRAPCOLS(1,3, B1)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + //2.8 аргумент - array + oParser = new parserFormula("WRAPCOLS(1,3, {1,2,3})", "A1", ws); + assert.ok(oParser.parse()); + array = oParser.calculate(); + assert.strictEqual(array.getElementRowCol(0, 0).getValue(), 1); + + oParser = new parserFormula("WRAPCOLS(1,3, B1:B2)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + + }); + QUnit.test("Test: \"BETA.INV\"", function (assert) { ws.getRange2("A2").setValue("0.685470581"); ws.getRange2("A3").setValue("8"); From 8b7613e684b2b9609f7b55fcefc3aba13e8a7c12 Mon Sep 17 00:00:00 2001 From: Igor Zotov Date: Mon, 31 Oct 2022 13:23:46 +0300 Subject: [PATCH 3/5] [se] Fix --- .../lookupandreferenceFunctions.js | 10 ++- .../spreadsheet-calculation/FormulaTests.js | 86 ++++++------------- 2 files changed, 31 insertions(+), 65 deletions(-) diff --git a/cell/model/FormulaObjects/lookupandreferenceFunctions.js b/cell/model/FormulaObjects/lookupandreferenceFunctions.js index 955cd55388..aa982ad9f7 100644 --- a/cell/model/FormulaObjects/lookupandreferenceFunctions.js +++ b/cell/model/FormulaObjects/lookupandreferenceFunctions.js @@ -326,14 +326,16 @@ function (window, undefined) { let _arg = arg[i]; if (cElementType.cellsRange === _arg.type || cElementType.cellsRange3D === _arg.type) { - _arg = _arg.getValue2(0,0); + //_arg = _arg.getValue2(0,0); + return new cError(cErrorType.wrong_value_type); } else if (cElementType.array === _arg.type) { - _arg = _arg.getElementRowCol(0, 0); + //_arg = _arg.getElementRowCol(0, 0); + return new cError(cErrorType.wrong_value_type); } _arg = _arg.tocNumber(); - if (arg1.type === cElementType.error) { - return arg1; + if (_arg.type === cElementType.error) { + return _arg; } _arg = _arg.toNumber(); let reverse = _arg < 0; diff --git a/tests/cell/spreadsheet-calculation/FormulaTests.js b/tests/cell/spreadsheet-calculation/FormulaTests.js index 11d105a228..4986efb347 100644 --- a/tests/cell/spreadsheet-calculation/FormulaTests.js +++ b/tests/cell/spreadsheet-calculation/FormulaTests.js @@ -2450,114 +2450,78 @@ $(function () { //2. аргументы - разные типы. нужно пербрать все аргументы //2.1 аргумент - number - oParser = new parserFormula("WRAPCOLS(1,3)", "A1", ws); + oParser = new parserFormula("CHOOSECOLS(1,1)", "A1", ws); assert.ok(oParser.parse()); assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); //2.2 аргумент - string - oParser = new parserFormula("WRAPCOLS(\"test\",3)", "A1", ws); + oParser = new parserFormula("CHOOSECOLS(\"test\",1)", "A1", ws); assert.ok(oParser.parse()); assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), "test"); //2.3 аргумент - bool - oParser = new parserFormula("WRAPCOLS(true,3)", "A1", ws); + oParser = new parserFormula("CHOOSECOLS(true,1)", "A1", ws); assert.ok(oParser.parse()); assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), "TRUE"); //2.4 аргумент - error - oParser = new parserFormula("WRAPCOLS(#VALUE!,3)", "A1", ws); + oParser = new parserFormula("CHOOSECOLS(#VALUE!,3)", "A1", ws); assert.ok(oParser.parse()); assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); //2.5 аргумент - empty - oParser = new parserFormula("WRAPCOLS(,2)", "A1", ws); + oParser = new parserFormula("CHOOSECOLS(,2)", "A1", ws); assert.ok(oParser.parse()); assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); //2.6 аргумент - cellsRange //2.7 аргумент - cell - oParser = new parserFormula("WRAPCOLS(B1, 10)", "A1", ws); + oParser = new parserFormula("CHOOSECOLS(B1, 1)", "A1", ws); assert.ok(oParser.parse()); - assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), "test2"); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), "q"); //2.8 аргумент - array - oParser = new parserFormula("WRAPCOLS({2;\"\";\"test\"},2)", "A1", ws); + oParser = new parserFormula("CHOOSECOLS({2;\"\";\"test\"},3)", "A1", ws); assert.ok(oParser.parse()); array = oParser.calculate(); - assert.strictEqual(array.getElementRowCol(0, 0).getValue(), 2); - assert.strictEqual(array.getElementRowCol(1, 0).getValue(), ''); - assert.strictEqual(array.getElementRowCol(0, 1).getValue(), 'test'); - assert.strictEqual(array.getElementRowCol(1, 1).getValue(), '#N/A'); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + + //2.8 аргумент - array + oParser = new parserFormula("CHOOSECOLS({2,\"\",\"test\"},3)", "A1", ws); + assert.ok(oParser.parse()); + array = oParser.calculate(); + + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), "test"); //2.2 аргумент - string - oParser = new parserFormula("WRAPCOLS(1,\"test\")", "A1", ws); + oParser = new parserFormula("CHOOSECOLS(1,\"test\")", "A1", ws); assert.ok(oParser.parse()); assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); //2.3 аргумент - bool - oParser = new parserFormula("WRAPCOLS(1,true)", "A1", ws); + oParser = new parserFormula("CHOOSECOLS(1,true)", "A1", ws); assert.ok(oParser.parse()); assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); //2.4 аргумент - error - oParser = new parserFormula("WRAPCOLS(1, #VALUE!)", "A1", ws); + oParser = new parserFormula("CHOOSECOLS(1, #VALUE!)", "A1", ws); assert.ok(oParser.parse()); assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); //2.5 аргумент - empty - oParser = new parserFormula("WRAPCOLS(1,)", "A1", ws); + oParser = new parserFormula("CHOOSECOLS(1,)", "A1", ws); assert.ok(oParser.parse()); - assert.strictEqual(oParser.calculate().getValue(), "#NUM!"); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); //2.6 аргумент - cellsRange //2.7 аргумент - cell - oParser = new parserFormula("WRAPCOLS(1,A1)", "A1", ws); + oParser = new parserFormula("CHOOSECOLS(1,A1)", "A1", ws); assert.ok(oParser.parse()); assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); - oParser = new parserFormula("WRAPCOLS(1,A1:B5)", "A1", ws); + oParser = new parserFormula("CHOOSECOLS(1,A1:B5)", "A1", ws); assert.ok(oParser.parse()); - assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); //2.8 аргумент - array - oParser = new parserFormula("WRAPCOLS(1,{2;\"\";\"test\"})", "A1", ws); - assert.ok(oParser.parse()); - assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); - - - //2. аргументы - разные типы. нужно пербрать все аргументы - //2.1 аргумент - number - oParser = new parserFormula("WRAPCOLS(1,3,1)", "A1", ws); - assert.ok(oParser.parse()); - assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); - - - //2.2 аргумент - string - oParser = new parserFormula("WRAPCOLS(1,3,\"test\")", "A1", ws); - assert.ok(oParser.parse()); - assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); - //2.3 аргумент - bool - oParser = new parserFormula("WRAPCOLS(1,3,true)", "A1", ws); - assert.ok(oParser.parse()); - assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); - //2.4 аргумент - error - oParser = new parserFormula("WRAPCOLS(1,3,#VALUE!)", "A1", ws); + oParser = new parserFormula("CHOOSECOLS(1,{2;\"\";\"test\"})", "A1", ws); assert.ok(oParser.parse()); assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); - //2.5 аргумент - empty - oParser = new parserFormula("WRAPCOLS(1,3,)", "A1", ws); - assert.ok(oParser.parse()); - assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); - //2.6 аргумент - cellsRange - //2.7 аргумент - cell - oParser = new parserFormula("WRAPCOLS(1,3, B1)", "A1", ws); - assert.ok(oParser.parse()); - assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); - //2.8 аргумент - array - oParser = new parserFormula("WRAPCOLS(1,3, {1,2,3})", "A1", ws); - assert.ok(oParser.parse()); - array = oParser.calculate(); - assert.strictEqual(array.getElementRowCol(0, 0).getValue(), 1); - - oParser = new parserFormula("WRAPCOLS(1,3, B1:B2)", "A1", ws); - assert.ok(oParser.parse()); - assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); - }); QUnit.test("Test: \"BETA.INV\"", function (assert) { From ec9f40e41170234028bf74c0bb16d4ba2e42a149 Mon Sep 17 00:00:00 2001 From: Igor Zotov Date: Mon, 31 Oct 2022 15:12:49 +0300 Subject: [PATCH 4/5] [se] Chooserows --- .../lookupandreferenceFunctions.js | 65 +++++--- cell/model/FormulaObjects/parserFormula.js | 7 + .../spreadsheet-calculation/FormulaTests.js | 141 ++++++++++++++++++ 3 files changed, 194 insertions(+), 19 deletions(-) diff --git a/cell/model/FormulaObjects/lookupandreferenceFunctions.js b/cell/model/FormulaObjects/lookupandreferenceFunctions.js index aa982ad9f7..ef0a38e024 100644 --- a/cell/model/FormulaObjects/lookupandreferenceFunctions.js +++ b/cell/model/FormulaObjects/lookupandreferenceFunctions.js @@ -67,7 +67,7 @@ function (window, undefined) { var _func = AscCommonExcel._func; cFormulaFunctionGroup['LookupAndReference'] = cFormulaFunctionGroup['LookupAndReference'] || []; - cFormulaFunctionGroup['LookupAndReference'].push(cADDRESS, cAREAS, cCHOOSE, cCHOOSECOLS, cCOLUMN, cCOLUMNS, cFORMULATEXT, + cFormulaFunctionGroup['LookupAndReference'].push(cADDRESS, cAREAS, cCHOOSE, cCHOOSECOLS, cCHOOSEROWS, cCOLUMN, cCOLUMNS, cFORMULATEXT, cGETPIVOTDATA, cHLOOKUP, cHYPERLINK, cINDEX, cINDIRECT, cLOOKUP, cMATCH, cOFFSET, cROW, cROWS, cRTD, cTRANSPOSE, cUNIQUE, cVLOOKUP, cXLOOKUP, cVSTACK, cHSTACK, cTOROW, cTOCOL, cWRAPROWS, cWRAPCOLS); @@ -281,22 +281,7 @@ function (window, undefined) { return new cError(cErrorType.wrong_value_type); }; - /** - * @constructor - * @extends {AscCommonExcel.cBaseFunction} - */ - function cCHOOSECOLS() { - } - - //***array-formula*** - cCHOOSECOLS.prototype = Object.create(cBaseFunction.prototype); - cCHOOSECOLS.prototype.constructor = cCHOOSECOLS; - cCHOOSECOLS.prototype.name = 'CHOOSECOLS'; - cCHOOSECOLS.prototype.argumentsMin = 2; - cCHOOSECOLS.prototype.argumentsMax = 253; - cCHOOSECOLS.prototype.argumentsType = [argType.reference, [argType.number]]; - cCHOOSECOLS.prototype.returnValueType = AscCommonExcel.cReturnFormulaType.array; - cCHOOSECOLS.prototype.Calculate = function (arg) { + function chooseRowsCols(arg, argument1, byCol) { var argError = cBaseFunction.prototype._checkErrorArg.call(this, arg); if (argError) { return argError; @@ -341,7 +326,7 @@ function (window, undefined) { let reverse = _arg < 0; _arg = Math.abs(_arg); _arg = parseInt(_arg); - if (_arg < 1 || _arg > dimension.col) { + if (_arg < 1 || (_arg > dimension.col && byCol) || (_arg > dimension.row && !byCol)) { return new cError(cErrorType.wrong_value_type); } @@ -349,10 +334,52 @@ function (window, undefined) { res = new cArray(); } - res.pushCol(matrix, reverse ? dimension.col - (_arg - 1) - 1 : _arg - 1); + if (byCol) { + res.pushCol(matrix, reverse ? dimension.col - (_arg - 1) - 1 : _arg - 1); + } else { + res.pushRow(matrix, reverse ? dimension.row - (_arg - 1) - 1 : _arg - 1); + } } return res ? res : new cError(cErrorType.wrong_value_type); + } + + /** + * @constructor + * @extends {AscCommonExcel.cBaseFunction} + */ + function cCHOOSECOLS() { + } + + //***array-formula*** + cCHOOSECOLS.prototype = Object.create(cBaseFunction.prototype); + cCHOOSECOLS.prototype.constructor = cCHOOSECOLS; + cCHOOSECOLS.prototype.name = 'CHOOSECOLS'; + cCHOOSECOLS.prototype.argumentsMin = 2; + cCHOOSECOLS.prototype.argumentsMax = 253; + cCHOOSECOLS.prototype.argumentsType = [argType.reference, [argType.number]]; + cCHOOSECOLS.prototype.returnValueType = AscCommonExcel.cReturnFormulaType.array; + cCHOOSECOLS.prototype.Calculate = function (arg) { + return chooseRowsCols(arg, arguments[1], true); + }; + + /** + * @constructor + * @extends {AscCommonExcel.cBaseFunction} + */ + function cCHOOSEROWS() { + } + + //***array-formula*** + cCHOOSEROWS.prototype = Object.create(cBaseFunction.prototype); + cCHOOSEROWS.prototype.constructor = cCHOOSEROWS; + cCHOOSEROWS.prototype.name = 'CHOOSEROWS'; + cCHOOSEROWS.prototype.argumentsMin = 2; + cCHOOSEROWS.prototype.argumentsMax = 253; + cCHOOSEROWS.prototype.argumentsType = [argType.reference, [argType.number]]; + cCHOOSEROWS.prototype.returnValueType = AscCommonExcel.cReturnFormulaType.array; + cCHOOSEROWS.prototype.Calculate = function (arg) { + return chooseRowsCols(arg, arguments[1]); }; /** diff --git a/cell/model/FormulaObjects/parserFormula.js b/cell/model/FormulaObjects/parserFormula.js index 70fb30d98b..9abb5a2e97 100644 --- a/cell/model/FormulaObjects/parserFormula.js +++ b/cell/model/FormulaObjects/parserFormula.js @@ -2722,6 +2722,13 @@ parserHelp.setDigitSeparator(AscCommon.g_oDefaultCultureInfo.NumberDecimalSepara } this.recalculate(); }; + cArray.prototype.pushRow = function (matrix, colNum) { + if (matrix && matrix[colNum]) { + this.array.push(matrix[colNum]); + this.recalculate(); + } + }; + /** diff --git a/tests/cell/spreadsheet-calculation/FormulaTests.js b/tests/cell/spreadsheet-calculation/FormulaTests.js index 4986efb347..a61cd92e88 100644 --- a/tests/cell/spreadsheet-calculation/FormulaTests.js +++ b/tests/cell/spreadsheet-calculation/FormulaTests.js @@ -2524,6 +2524,147 @@ $(function () { assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); }); + QUnit.test("Test: \"CHOOSEROWS\"", function (assert) { + //1. добавляем общие тесты + + ws.getRange2("A1").setValue("1"); + ws.getRange2("A2").setValue("2"); + ws.getRange2("A3").setValue(""); + ws.getRange2("A4").setValue("4"); + ws.getRange2("A5").setValue("#N/A"); + ws.getRange2("A6").setValue("f"); + + ws.getRange2("B1").setValue("q"); + ws.getRange2("B2").setValue("w"); + ws.getRange2("B3").setValue("e"); + ws.getRange2("B4").setValue("test"); + ws.getRange2("B5").setValue("hhh"); + ws.getRange2("B6").setValue("g"); + + ws.getRange2("C1").setValue("r"); + ws.getRange2("C2").setValue("3"); + ws.getRange2("C3").setValue("5"); + ws.getRange2("C4").setValue(""); + ws.getRange2("C5").setValue("6"); + ws.getRange2("C6").setValue("h"); + + + oParser = new parserFormula("CHOOSEROWS(A1:C6;-1;1)", "A1", ws); + assert.ok(oParser.parse()); + let array = oParser.calculate(); + + assert.strictEqual(array.getElementRowCol(0, 0).getValue(), 'f'); + assert.strictEqual(array.getElementRowCol(1, 0).getValue(), 1); + + assert.strictEqual(array.getElementRowCol(0, 1).getValue(), 'g'); + assert.strictEqual(array.getElementRowCol(1, 1).getValue(), 'q'); + + assert.strictEqual(array.getElementRowCol(0, 2).getValue(), 'h'); + assert.strictEqual(array.getElementRowCol(1, 2).getValue(), 'r'); + + + + oParser = new parserFormula("CHOOSEROWS(A1:C6;-2;3)", "A1", ws); + assert.ok(oParser.parse()); + array = oParser.calculate(); + + assert.strictEqual(array.getElementRowCol(0, 0).getValue(), '#N/A'); + assert.strictEqual(array.getElementRowCol(1, 0).getValue(), ''); + + assert.strictEqual(array.getElementRowCol(0, 1).getValue(), 'hhh'); + assert.strictEqual(array.getElementRowCol(1, 1).getValue(), 'e'); + + assert.strictEqual(array.getElementRowCol(0, 2).getValue(), 6); + assert.strictEqual(array.getElementRowCol(1, 2).getValue(), 5); + + + oParser = new parserFormula("CHOOSEROWS(A1:C6;-4;20)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + + oParser = new parserFormula("CHOOSEROWS(A1:C6;-10;4)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + + oParser = new parserFormula("CHOOSEROWS(A1:C6;-2;0)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + + + //2. аргументы - разные типы. нужно пербрать все аргументы + //2.1 аргумент - number + oParser = new parserFormula("CHOOSEROWS(1,1)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + //2.2 аргумент - string + oParser = new parserFormula("CHOOSEROWS(\"test\",1)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), "test"); + //2.3 аргумент - bool + oParser = new parserFormula("CHOOSEROWS(true,1)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), "TRUE"); + //2.4 аргумент - error + oParser = new parserFormula("CHOOSEROWS(#VALUE!,3)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + //2.5 аргумент - empty + oParser = new parserFormula("CHOOSEROWS(,2)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + //2.6 аргумент - cellsRange + //2.7 аргумент - cell + oParser = new parserFormula("CHOOSEROWS(B1, 1)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), "q"); + + //2.8 аргумент - array + oParser = new parserFormula("CHOOSEROWS({2;\"\";\"test\"},3)", "A1", ws); + assert.ok(oParser.parse()); + array = oParser.calculate(); + + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), "test"); + + //2.8 аргумент - array + oParser = new parserFormula("CHOOSEROWS({2,\"\",\"test\"},3)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + + + //2.2 аргумент - string + oParser = new parserFormula("CHOOSEROWS(1,\"test\")", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + //2.3 аргумент - bool + oParser = new parserFormula("CHOOSEROWS(1,true)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + //2.4 аргумент - error + oParser = new parserFormula("CHOOSEROWS(1, #VALUE!)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + //2.5 аргумент - empty + oParser = new parserFormula("CHOOSEROWS(1,)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + + + //2.6 аргумент - cellsRange + //2.7 аргумент - cell + oParser = new parserFormula("CHOOSEROWS(1,A1)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getElementRowCol(0, 0).getValue(), 1); + + oParser = new parserFormula("CHOOSEROWS(1,A1:B5)", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + + //2.8 аргумент - array + oParser = new parserFormula("CHOOSEROWS(1,{2;\"\";\"test\"})", "A1", ws); + assert.ok(oParser.parse()); + assert.strictEqual(oParser.calculate().getValue(), "#VALUE!"); + }); + QUnit.test("Test: \"BETA.INV\"", function (assert) { ws.getRange2("A2").setValue("0.685470581"); ws.getRange2("A3").setValue("8"); From 69c4a73ae370b4267a120fbb3920f56b2fd33e7c Mon Sep 17 00:00:00 2001 From: Igor Zotov Date: Mon, 31 Oct 2022 15:14:55 +0300 Subject: [PATCH 5/5] [se] Xlfn flag --- cell/model/FormulaObjects/lookupandreferenceFunctions.js | 2 ++ 1 file changed, 2 insertions(+) diff --git a/cell/model/FormulaObjects/lookupandreferenceFunctions.js b/cell/model/FormulaObjects/lookupandreferenceFunctions.js index ef0a38e024..722d3db2da 100644 --- a/cell/model/FormulaObjects/lookupandreferenceFunctions.js +++ b/cell/model/FormulaObjects/lookupandreferenceFunctions.js @@ -359,6 +359,7 @@ function (window, undefined) { cCHOOSECOLS.prototype.argumentsMax = 253; cCHOOSECOLS.prototype.argumentsType = [argType.reference, [argType.number]]; cCHOOSECOLS.prototype.returnValueType = AscCommonExcel.cReturnFormulaType.array; + cCHOOSECOLS.prototype.isXLFN = true; cCHOOSECOLS.prototype.Calculate = function (arg) { return chooseRowsCols(arg, arguments[1], true); }; @@ -378,6 +379,7 @@ function (window, undefined) { cCHOOSEROWS.prototype.argumentsMax = 253; cCHOOSEROWS.prototype.argumentsType = [argType.reference, [argType.number]]; cCHOOSEROWS.prototype.returnValueType = AscCommonExcel.cReturnFormulaType.array; + cCHOOSEROWS.prototype.isXLFN = true; cCHOOSEROWS.prototype.Calculate = function (arg) { return chooseRowsCols(arg, arguments[1]); };