Forum Discussion
Product of numbers in a row in a dynamic array
- Oct 12, 2021
This is something I have been complaining about for a couple of years or so now but, as JKPieterse says, the definitive solution is to be found in the Insiders beta Channel. BYROW will return each row as a distinct range reference and supports any relevant calculation.
As an interim workaround, the multiplication of positive numbers may be performed by using logarithms
= EXP( MMULT(LN(array#), {1;1;1}) )
What you get from Microsoft is that Excel never has handled 'arrays of arrays' or 'arrays of ranges' and they need to maintain backward compatibility. Now, however, it has become important because, with dynamic arrays, one keeps hitting the problem. Your formula
=INDEX(A1#,A7,0)
returns a range object; by that, COLUMN would return sheet column numbers and ISREF would return TRUE. As soon as you add the # to A7, Excel recognises that you want an array of ranges and blocks the calculation, instead returning an array of single values (it is not a range).
As for
=PRODUCT(INDEX(A1#,A7#,0))
that just suggests that Excel knew perfectly well what you wanted all along, but refused to give it to you!
Even with the helper functions MAKEARRAY etc., it can be difficult to return arrays of arrays.
I wanted to ask for your thoughts on one issue with the workaround formula you gave me. It doesn't work if there is a 0 in the array because ln(0) is an error. Is there a way to get that to work? I need the 0 result of the product as it has a semantic meaning.
- PeterBartholomew1Oct 13, 2021Silver Contributor
"... other relationships ..." big grin!
The solution depends upon the semantic meaning. Taking it as zero, rather than omitted:
= LET( selectedValues, FILTER(values,Tabell1[Option]=selected), ones, SEQUENCE(COLUMNS(selectedValues),,,0), logs, LN(ABS(selectedValues)), zeroTest, ISERROR(logs), arr, IF(zeroTest, 0, logs), result, MMULT(arr, ones), isZero, MMULT(SIGN(zeroTest), ones), IF(isZero, 0, EXP(result)))Once you have Lambda functions
= LET( PRODUCTλ, LAMBDA(row, PRODUCT(row)), BYROW(array#, PRODUCTλ))would be preferable. An interesting features of these solutions is that neither looks remotely similar to a traditional spreadsheet formula.
- LorenzoJun 17, 2024Silver Contributor
A friend of mine THANKs YOU++ for your option to perform a PRODUCT row by row w/2021. She also needed that it works with negative nums & to ignore BLANKs. We spent a couple of hours together... Attached is what we came up with (also ignore Text values & raises 1st error if any). Seems to work...
(we could observe tiny differences with PRODUCT on some sets but she can live with that 🙂- PeterBartholomew1Jun 17, 2024Silver Contributor
A walk down memory lane. How things have changed over the past 5 years!
The math is easily followed but you include a masterclass in error handling. Maybe I should try to work it into Craig Hatmaker's Component-Based Software Engineering modules. Once they are nested several deep, it becomes difficult to identify the module and error type that is the source of a failed formula.
An alternative way of counting negatives could be
= IF(XOR(SIGN(nums < 0))My formulas are so far from the beaten track of normal spreadsheeting that it is good to find someone like you who can understand and improve on my formulas.

- boukasaOct 13, 2021Brass Contributor
PeterBartholomew1 I can't quite match/figure out how to match your suggestion to my structure. (This is a lot of hoops to get through given that ByRow is coming! But I don't have access to it.)
Here's what's really happening. I have a list of donors who will give to any of a list of nonprofits if certain criteria match between the donor's rules and criteria about the nonprofit. Each donor specifies criteria the she excludes or allows. For example, "allow North Texas, exclude Oklahoma, allow women's causes, exclude animal causes, allow this nonprofit, exclude that nonprofit."
I can pick a particular nonprofit, look up all its criteria, match it to the allow/exclude rules for the donors, and a complicated formula creates an array that looks like this:
criteria1 criteria2 criteria3
donor1 exclude no rule allow
donor2 allow no rule no rule
donor3 no rule no rule no rule
One or more excludes should exclude the donor, otherwise one or more allows should match the donor. No excludes and no allows also means the donor is not matched. Multiplication is a one-to-one map onto this logic if 0 is exclude, 1 is no rule, and >1 is allow.
criteria1 criteria2 criteria3
donor1 0 1 2
donor2 2 1 1
donor3 1 1 1
By multiplying the numbers together, the result is any number >=2 means the donor can support this nonprofit. Any single exclude will result in 0. Any non-rule leaves the result alone (1). Any allow (2) will get the result out of the 0/1 range.
Since my result set is an array but not a table, I'm not sure how to use your filter suggestion. I mean "exclude any 0 in the row."
Eventually this will all end up in a database where it belongs, but boy Excel makes a proof of concept extremely fast and easy.
By the way, your comment about these lambdas being unlike anything seen in spreadsheets before, I had a thought about that. The array functions make the spreadsheet data much more like a database. Maybe one day there will be an integration of SQL directly into the spreadsheet. But I think it's interesting that these two things intersect: (a) lambda - row by row calculation - is exactly what you attempt to avoid in a query, and conversely (b) the "instant total 2d reduction" that I'm trying to get around here is actually quite difficult to make happen in SQL. So this whole powerful array/lambda paradigm seems to be at the intersection of the gap between (older) spreadsheets and SQL.
- PeterBartholomew1Oct 13, 2021Silver Contributor
That changes everything. You are not really interested in the product at all; it is merely an AND condition looking for an instance of "exclude". Negate the condition and it can be combined by addition, representing OR.
I have left the table because it resizes to accommodate fresh data, but no longer use the structured references.
= LET( selectedValues, FILTER(values,Tabell1[Option]=selected), ones, SEQUENCE(COLUMNS(selectedValues),,,0), inc, SIGN(selectedValues="allow"), exc, SIGN(selectedValues="exclude"), included, MMULT(inc, ones), excluded, MMULT(exc, ones), IF(NOT(excluded) * included, "Match", "--- ") )or with Lambda functions
= LET( INCLUDEλ, LAMBDA(row, OR(row="allow")), EXCLUDEλ, LAMBDA(row, OR(row="exclude")), excluded, BYROW(array#, EXCLUDEλ), included, BYROW(array#, INCLUDEλ), IF(NOT(excluded) * included, "Match", "--- ") )