BYROW #CALC error

lrobbo314

Well-known Member
Joined
Jul 14, 2008
Messages
3,927
Office Version
  1. 365
Platform
  1. Windows
I am trying to cut up a string into chunks of 3 character long strings to see how many times there are 3 sequential letters in the string.

When I reference a range, e.g. D62#, the BYROW formula works as expected. But, when I substitute D62# for the formula that is in it, I get #CALC errors, empty array.

I don't understand why this is happening or how to fix it.

Book3
BCDEF
60abc123def
61
621abc1#CALC!
632bc10#CALC!
643c120#CALC!
6541230#CALC!
66523d0#CALC!
6763de0#CALC!
687def1#CALC!
Sheet1
Cell Formulas
RangeFormula
C62:C68C62=SEQUENCE(LEN(B60)-2)
D62:D68D62=MID(B60,C62#,3)
E62:E68E62=BYROW(D62#,LAMBDA(br,LET(c,CODE(TXT2ARR(UPPER(br))),a,DROP(c,1),b,DROP(c,-1),x,(a>64)*(a<91)*a,y,(b>64)*(b<91)*b,--(SUM(--(x-y=1))=2))))
F62:F68F62=BYROW(MID(B60,C62#,3),LAMBDA(br,LET(c,CODE(TXT2ARR(UPPER(br))),a,DROP(c,1),b,DROP(c,-1),x,(a>64)*(a<91)*a,y,(b>64)*(b<91)*b,--(SUM(--(x-y=1))=2))))
Dynamic array formulas.


The code for the TXT2ARR function is

Excel Formula:
=LAMBDA(text,MID(text,SEQUENCE(LEN(text)),1))
 

Excel Facts

Easy bullets in Excel
If you have a numeric keypad, press Alt+7 on numeric keypad to type a bullet in Excel.
I agree it seems like it should work. Evaluating the F column formula it seems to be failing at the TXT2ARR function.

Here's an approach in column G that doesn't rely on TXT2ARR

Book1
ABCDEFGH
60abc123def
61
621abc1#CALC!1
632bc10#CALC!0
643c120#CALC!0
6541230#CALC!0
66523d0#CALC!0
6763de0#CALC!0
687def1#CALC!1
69
Sheet3
Cell Formulas
RangeFormula
C62:C68C62=SEQUENCE(LEN(B60)-2)
D62:D68D62=MID(B60,C62#,3)
E62:E68E62=BYROW(D62#,LAMBDA(br,LET(c,CODE(TXT2ARR(UPPER(br))),a,DROP(c,1),b,DROP(c,-1),x,(a>64)*(a<91)*a,y,(b>64)*(b<91)*b,--(SUM(--(x-y=1))=2))))
F62:F68F62=BYROW(MID(B60,C62#,3),LAMBDA(br,LET(c,CODE(TXT2ARR(UPPER(br))),a,DROP(c,1),b,DROP(c,-1),x,(a>64)*(a<91)*a,y,(b>64)*(b<91)*b,--(SUM(--(x-y=1))=2))))
G62:G68G62=BYROW(UPPER(MID(B60,C62#,3)),LAMBDA(t,LET(a,CODE(MID(t,1,1)),b,CODE(MID(t,2,1)),c,CODE(MID(t,3,1)),(c-b=1)*(b-a=1)*(a>=CODE("A"))*(c<=CODE("Z")))))
Dynamic array formulas.
 
Upvote 0
Solution
Might be a minute before I get a chance to try it out. But thank you for the response. Looks great.
 
Upvote 0

Forum statistics

Threads
1,215,129
Messages
6,123,218
Members
449,091
Latest member
jeremy_bp001

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top