Forum Discussion
How to split cell containing FRACTION into two cells including Numerator and denominator
- Apr 20, 2022
Try this.
=TRANSPOSE(FILTERXML("<y><z>"&SUBSTITUTE(SUBSTITUTE(TEXT(B8,"# ????/????"),"/","#"),"#","</z><z>")&"</z></y>","//z"))
Looking back, I wonder why I selected CHOOSE to combine numerators and denominators into an array.
= LET(
fraction, TEXT(values,"????/????"),
numerator, TEXTBEFORE(fraction,"/"),
denominator, TEXTAFTER(fraction,"/"),
VALUE(HSTACK(numerator,denominator))
)
Of course, had it not been for Microsoft's dreadful decision not to support nested arrays / arrays of arrays, life would be a lot simpler. Unfortunately
= LET(
fraction, TEXT(values,"????/????"),
TEXTSPLIT(fraction,"/")
)
returns only the numerators. A trick to return both numerator and denominators is to join the value array before splitting it two ways
= LET(
fraction, TEXT(values,"????/????"),
string, TEXTJOIN("\",,fraction),
VALUE(TEXTSPLIT(string,"/","\"))
)
The sad fact is that the majority of formulas I now write contain obscure workarounds for the 'array of arrays' problem.
This is unfortunate because I would define a modern spreadsheet as an environment in which arrays of arrays may be manipulated to facilitate calculation. So why not do it properly? Excel with dynamic arrays is so nearly there in terms of functionality. The user interface needs further development to support testing and audit but that can evolve over time.
- djclementsNov 11, 2023Bronze Contributor
PeterBartholomew1 I hear you! As mentioned, the TEXTSPLIT function is not capable of spilling its results with an array of values, unless implementing some sort of workaround. TEXTJOIN works but is limited to 32,767 characters. In this case, with each text string containing 9 characters + 1 delimiter, if the dataset contained more than 3,276 rows of data, TEXTJOIN would fail with the #CALC! error.
The only other workaround I've seen for creating an array of arrays is to use the REDUCE function with VSTACK. For example:
=REDUCE({"Numerator","Denominator"}, A2:A10000, LAMBDA(v,n, VSTACK(v, --TEXTSPLIT(TEXT(n, "????/????"), "/"))))
However, this method performs very poorly with large datasets, due to its iterative nature and repeated use of VSTACK for each row in the range. If the dataset is large enough, it may even cause Excel to crash.
Your first example, though, using TEXTBEFORE and TEXTAFTER with HSTACK is lightning-fast in comparison when used with large datasets, and is definitely the way to go. My take would be to use something like this:
=LET( arr, TEXT(A2:A10000, "????/????"), --HSTACK(TEXTBEFORE(arr, "/"), TEXTAFTER(arr, "/")) )
...which is basically the same as what you've done, but with a double-negative to convert the text to numbers, rather that the VALUE function. Cheers! 🙂
- PeterBartholomew1Nov 11, 2023Silver Contributor
I think we are just about in complete agreement. There are a couple of other techniques relevant to the array of arrays limitation. One is to replace the sequence of unit steps by a sequence of bisections as described by OwenPrice in his newsletter.
(5) Excel LAMBDA Spotlight: Bisected Map with BMAPλ | LinkedIn
Another technique that also appears to be far more efficient than REDUCE/VSTACK is to use SCAN or MAP but to convert the resulting array LET variables to Thunks. This was described by @lori_m in a
community discussion.I believe that the concept of relative referencing should be left behind in its entirety (as simply representing an inferior approach to scanning the terms of a list or an array). That is a difficult case to argue when results that are comprised of nested arrays (practically all spreadsheet solutions including data presented as pivot tables) are so difficult to generate.