Forum Discussion
Profit Formula Challenge
- Dec 31, 2020
Don't forget that Twifoo intended the challenge to be an examination of the use of advanced array methods available within traditional Excel. The dislike of CSE is understandable but is simply a by-product of the user-interface design.
As I noted earlier, I had trained myself to commit all formulas with CSE but I would have preferred not to need it. For some reason my proposal to reverse the conventions, that is to use CSE to introduce the additional implicit intersection step and use Enter to allow the calculation to proceed as a simple array operation was not well-received 🙂
I share the views of SergeiBaklan and Twifoo in that I see no need to avoid {1,-1,1,-1} as an array constant on the grounds that the notation is similar to the CSE notation. The array constant is an important element of array calculation. They need to be used with care, not because they are arrays, but because they are constants. If there exists a possibility that they may change, a named variable would be more appropriate than a constant embedded within a formula.
I confess, I have never seen or attempted a formula this large in Excel.
= LET(
crosstab, SUMIFS(Amounts, Types, listTypes, Branches, HdrBranches),
OperatingProfit, MMULT( TRANSPOSE(SignCashFlow), crosstab ),
ProfitableBranches, COUNT( IF(OperatingProfit > 0, 1) ),
LossmakingBranches, COUNT( IF(OperatingProfit <0, 1) ),
MaxProfit, MAX(OperatingProfit),
BestPerforming, XLOOKUP( MaxProfit, OperatingProfit, HdrBranches ),
MaxLoss, MIN(OperatingProfit),
WorstPerforming, XLOOKUP( MaxLoss, OperatingProfit, HdrBranches ),
MinGain, MIN(IF(OperatingProfit>0, OperatingProfit) ),
MinGainBranch, XLOOKUP( MinGain, OperatingProfit, HdrBranches ),
MinLoss, MAX(IF(OperatingProfit<0, OperatingProfit) ),
MinLossBranch, XLOOKUP( MinLoss, OperatingProfit, HdrBranches ),
CHOOSE({1;2;3;4;5;6;7;8},
SUM(OperatingProfit),
ProfitableBranches,
LossmakingBranches,
BestPerforming,
WorstPerforming,
MinGainBranch,
MinLossBranch,
MaxProfit-MaxLoss ) )
Would it be better to break the calculation into parts even though it would mean recalculating the SUMIFS calculation within formula? I could, for example, have produced an array of MAX/MINs and then performed an XLOOKUP on the array.
Alternatively, should I have nested the MAX/MINs within the XLOOKUP to reduce the count of LET parameters?