ATEXTSPLIT

=ATEXTSPLIT(ar,dl,ea)

ar
array strings, 1D vertical
dl
string, one or more characters
ea
0 or 1, 0 or omitted ignores empty ; 1 does not ignore empty

array text split by any delimiter,(one or more chars), fine-tuned for complex scenarios

Xlambda

Well-known Member
Joined
Mar 8, 2021
Messages
832
Office Version
  1. 365
Platform
  1. Windows
ATEXTSPLIT array text split by any delimiter,(one or more chars), fine-tuned for complex scenarios.
Wrote this function inspired by MrExcel video: Excel TEXTJOIN And The Need For TEXTSPLIT with Ann K. Emery - 2407
The idea was to create a function that is clean and robust, does not call other functions, non-recursive, no FILTERXML, and uses same arguments as TEXTJOIN. What TEXTJOIN joins, ATEXTSPLIT should be able to split it back like it was, with same arguments. When we join, we choose the delimiter, but when we split imported data, things can go quite tricky.
ar: array 1D vertical, dl: delimiter, any string , ea: empty argument , 0 or omitted - ignores empty ; 1 - does not ignore empty
Note: There are 2 special characters in the formula, (h,"º",d,"ª"), first variables after "LET" . These should be changed if any of them is found on the array of strings. Formula advises if this happens.
Excel Formula:
=LAMBDA(ar,dl,ea,
    LET(h,"º",d,"ª",ch,ISNUMBER(SEARCH(CHOOSE({1,2},h,d),ar)),
       a,SUBSTITUTE(ar,dl,d),b,IF(ea,a,SUBSTITUTE(SUBSTITUTE(TRIM(SUBSTITUTE(SUBSTITUTE(a," ",h),d," "))," ",d),h," ")),
       n,LEN(b)-LEN(SUBSTITUTE(b,d,""))+1,c,MAX(n),sc,SEQUENCE(,c),
       x,SEARCH(h,SUBSTITUTE(d&b,d,h,sc)),y,SEARCH(h,SUBSTITUTE(b&d,d,h,sc)),m,IFERROR(MID(b,x,y-x),""),
       IF(OR(ch),"change special chars",IFERROR(--m,m))
    )
)
LAMBDA 7.0.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXYZAAABACADAEAFAGAHAI
1TEXTJOINATEXTSPLIT
2empty ignoredempty not ignored2 charsempty ignored
3empty not ignoredea arg.=0ea arg.=1delimiterea arg.=0
4sample=TEXTJOIN(",",0,A5:D5)=ATEXTSPLIT(F5:F7,",",)=ATEXTSPLIT(F5:F7,",",1)=ATEXTSPLIT(T5:T7,"><",)LEN check
5a4ca,4,,ca4ca4ca><6.8><ta6.8t131
6d0.5d,,,0.5d0.5d0.5><2.4 w><2.4 w600
7g hi 2k l3 ng h,i 2,k l,3 ng hi 2k l3 ng hi 2k l3 n<Ac4><gh>< ><<Ac4gh 421
8space
9empty ignoredea arg.=0ea arg.=1empty not ignored
10=TEXTJOIN(",",,A5:D5)=ATEXTSPLIT(F11:F13,",",)=ATEXTSPLIT(F11:F13,",",1)ea arg.=1
11a,4,ca4ca4c=ATEXTSPLIT(T5:T7,"><",1)LEN check
12d,0.5d0.5d0.5a6.8t1310
13g h,i 2,k l,3 ng hi 2k l3 ng hi 2k l3 n2.4 w0600
14<Ac4gh 4210
15Complex scenariospace followed by an empty string
16empty ignoredempty not ignored
17ea arg.=0ea arg.=1error debug.
18sample=ATEXTSPLIT(F19:F22,",",)=ATEXTSPLIT(F19:F22,",",1)=ATEXTSPLIT(X19,",",)
19a,b,c,2.3,,d e,abc2.3d eabc2.3d ea,ºb,cchange special chars
20,,g,,h, ,1.8gh 1.8gh 1.8=ATEXTSPLIT(X21,",",1)
21, k m, ,4.9, ,p k m 4.9 p k m 4.9 pa,ªb,cchange special chars
22, ,,x 4, ,, x 4 x 4
23
24Important Obs.: -two delimiters next to each other ( ,, ) , hold an empty string between them that can be ignored or not depending of "ea" argument
25 -two delimiters sep by space ( , , ) , hold a space between them, and can not be ignored, no matter of "ea" argument
26 We can check this behaviour with LEN function. (same rule applies for leading or trailing delimiters)
27
28=LEN(H19#)=LEN(N19#)
29111331113030
30111300010113
31413110413110
32151000105100
33
34- if values themselves embed inner spaces, could be important to keep them (like special codes with fixed length that follow a pattern),TRIM tweaks can not be used
35
36ex. code patternsample=ATEXTSPLIT(F37:F38,"/",)=LEN(H37#)
37fixed with 4 pos.a bc/a b/ bcda bca b bcd444
38/____ /ab d/ d/a ab d da 444
39/xxxx/check:pattern is kept
40
ATEXTSPLIT post
Cell Formulas
RangeFormula
H4,N36,H36,N28,H28,Z18,Z20,N18,H18,F10,X11,N10,H10,F4,X4,N4H4=FORMULATEXT(H5)
H5:K7,H11:K13H5=ATEXTSPLIT(F5:F7,",",)
N5:Q7,N11:Q13N5=ATEXTSPLIT(F5:F7,",",1)
X5:Z7X5=ATEXTSPLIT(T5:T7,"><",)
AC5:AE7,AC12:AF14AC5=LEN(X5#)
F5:F7F5=TEXTJOIN(",",0,A5:D5)
X12:AA14X12=ATEXTSPLIT(T5:T7,"><",1)
F11:F13F11=TEXTJOIN(",",,A5:D5)
H19:L22H19=ATEXTSPLIT(F19:F22,",",)
N19:T22N19=ATEXTSPLIT(F19:F22,",",1)
Z19Z19=ATEXTSPLIT(X19,",",)
Z21Z21=ATEXTSPLIT(X21,",",1)
H29:L32,N29:T32H29=LEN(H19#)
H37:J38H37=ATEXTSPLIT(F37:F38,"/",)
N37:P38N37=LEN(H37#)
Dynamic array formulas.
 
Upvote 0
Playing with the versatility of various functions that we have so far. Transforming data in a proper data set.
LAMBDA 1.1.2.xlsx
ABCDEFGHIJKLMNOP
1sampleChallenge: Single cell formula to transform sample into this:
2
3Prod 1Prod 2Prod 3Prod 4Report2020/2021
420202021202020212020202120202021MonthProd 1Prod 2Prod 3Prod 4
5Jan23.416.218.321.131.714.519.817.9Jan23.4/16.218.3/21.131.7/14.519.8/17.9
6Feb18.713.523.211.914.615.318.325.6Feb18.7/13.523.2/11.914.6/15.318.3/25.6
7Mar30.224.733.324.835.129.514.819.1Mar30.2/24.733.3/24.835.1/29.514.8/19.1
8
new ATJ 3
 
LAMBDA 1.1.2.xlsx
ABCDEFGHIJKLMNOPQR
1sample
2Prod 1Prod 2Prod 3Prod 4step1step 2
320202021202020212020202120202021=ATEXTJOIN(B4:I6,{"/","-"})=ATEXTSPLIT(K4#,"-")
4Jan23.416.218.321.131.714.519.817.923.4/16.2-18.3/21.1-31.7/14.5-19.8/17.923.4/16.218.3/21.131.7/14.519.8/17.9
5Feb18.713.523.211.914.615.318.325.618.7/13.5-23.2/11.9-14.6/15.3-18.3/25.618.7/13.523.2/11.914.6/15.318.3/25.6
6Mar30.224.733.324.835.129.514.819.130.2/24.7-33.3/24.8-35.1/29.5-14.8/19.130.2/24.733.3/24.835.1/29.514.8/19.1
7step 3
8=AREPORT(N4#,A4:A6,AVCLEAN(B2:H2),,,"Month")
9MonthProd 1Prod 2Prod 3Prod 4
10Jan23.4/16.218.3/21.131.7/14.519.8/17.9
11functions on minisheetFeb18.7/13.523.2/11.914.6/15.318.3/25.6
12new ATEXTJOINMar30.2/24.733.3/24.835.1/29.514.8/19.1
13new ATEXTSPLITstep 4step 5
14AREPORT=ATEXTJOIN(B3:I3,{"/",","})=ATEXTSPLIT(K15)
15AVCLEAN (3rd post)2020/2021,2020/2021,2020/2021,2020/20212020/20212020/20212020/20212020/2021
16AFILLstep 6step 7
17AOVERLAP=ARESIZE(N15,1,1)=AFILL({"Report",""},N18)
18ARESIZE2020/2021Report2020/2021
19
20step 8
21=AOVERLAP(M9#,P18#,-1,1)
22 Report2020/2021
23MonthProd 1Prod 2Prod 3Prod 4
24Jan23.4/16.218.3/21.131.7/14.519.8/17.9
25Feb18.7/13.523.2/11.914.6/15.318.3/25.6
26all 8 steps in a single cell dynamic formula :Mar30.2/24.733.3/24.835.1/29.514.8/19.1
27
28=AOVERLAP(AREPORT(ATEXTSPLIT(ATEXTJOIN(B4:I6,{"/","-"}),"-"),A4:A6,AVCLEAN(B2:H2),,,"Month"),AFILL({"Report",""},ARESIZE(ATEXTSPLIT(ATEXTJOIN(B3:I3,{"/",","})),1,1)),-1,1)
29
30 Report2020/2021
31MonthProd 1Prod 2Prod 3Prod 4
32Jan23.4/16.218.3/21.131.7/14.519.8/17.9
33Feb18.7/13.523.2/11.914.6/15.318.3/25.6
34Mar30.2/24.733.3/24.835.1/29.514.8/19.1
35
new ATJ 4
Cell Formulas
RangeFormula
N3,M21,N17,P17,K14,N14,M8,K3N3=FORMULATEXT(N4)
K4:K6K4=ATEXTJOIN(B4:I6,{"/","-"})
N4:Q6N4=ATEXTSPLIT(K4#,"-")
M9:Q12M9=AREPORT(N4#,A4:A6,AVCLEAN(B2:H2),,,"Month")
K15K15=ATEXTJOIN(B3:I3,{"/",","})
N15:Q15N15=ATEXTSPLIT(K15)
N18N18=ARESIZE(N15,1,1)
P18:Q18P18=AFILL({"Report",""},N18)
M22:Q26M22=AOVERLAP(M9#,P18#,-1,1)
A28A28=FORMULATEXT(M30)
M30:Q34M30=AOVERLAP(AREPORT(ATEXTSPLIT(ATEXTJOIN(B4:I6,{"/","-"}),"-"),A4:A6,AVCLEAN(B2:H2),,,"Month"),AFILL({"Report",""},ARESIZE(ATEXTSPLIT(ATEXTJOIN(B3:I3,{"/",","})),1,1)),-1,1)
Dynamic array formulas.
 
Backwards challenge, transform previous result into initial form design using a single cell full dynamic formula.
LAMBDA 1.1.2.xlsx
ABCDEFGHIJKLMNOPQR
1sampleBackward challenge: Single cell formula to transform sample into this:
2
3Report2020/2021Prod 1Prod 2Prod 3Prod 4
4MonthProd 1Prod 2Prod 3Prod 420202021202020212020202120202021
5Jan23.4/16.218.3/21.131.7/14.519.8/17.9Jan23.416.218.321.131.714.519.817.9
6Feb18.7/13.523.2/11.914.6/15.318.3/25.6Feb18.713.523.211.914.615.318.325.6
7Mar30.2/24.733.3/24.835.1/29.514.8/19.1Mar30.224.733.324.835.129.514.819.1
8
9step 1step 2
10=ATEXTSPLIT(B5:E7,"/")=ARESIZE(D11#,ROWS(B5:E7),COLUMNS(D11#)*COLUMNS(B5:E7))
1123.416.223.416.218.321.131.714.519.817.9
1218.321.118.713.523.211.914.615.318.325.6
1331.714.530.224.733.324.835.129.514.819.1
1419.817.9step 3step 3'
1518.713.5=ATEXTSPLIT(C3,"/")=COLUMNS(G16#)
1623.211.9202020212
1714.615.3
1818.325.6step 4
1930.224.7=ATEXTSPLIT(ATEXTJOIN(B4:E4,REPT(",.",K16-1)&","))
2033.324.8Prod 1.Prod 2.Prod 3.Prod 4
2135.129.5
2214.819.1step 5
23=INDEX(G16#,MOD(SEQUENCE(,COLUMNS(G11#))-1,2)+1)
24functions minisheet20202021202020212020202120202021
25new ATEXTSPLIT
26new ATEXTJOINstep 6
27AREPORT=AREPORT(G11#,G5:G7,G24#)
28ARESIZE 20202021202020212020202120202021
29APP2VJan23.416.218.321.131.714.519.817.9
30Feb18.713.523.211.914.615.318.325.6
31Mar30.224.733.324.835.129.514.819.1
32
33step 7
34=APP2V(G20#,G28#,,-1)
35 Prod 1.Prod 2.Prod 3.Prod 4
3620202021202020212020202120202021
37Jan23.416.218.321.131.714.519.817.9
38Feb18.713.523.211.914.615.318.325.6
39Mar30.224.733.324.835.129.514.819.1
40single cell dynamic LET
41 =LET(ma,B5:E7,p,B4:E4,y,C3,m,A5:A7,ts,ATEXTSPLIT(ma,"/"),nm,ARESIZE(ts,ROWS(ma),COLUMNS(ts)*COLUMNS(ma)),ys,ATEXTSPLIT(y,"/"),cy,COLUMNS(ys), pa,ATEXTSPLIT(ATEXTJOIN(p,REPT(",.",cy-1)&",")),ya,INDEX(ys,MOD(SEQUENCE(,COLUMNS(nm))-1,cy)+1),r,AREPORT(nm,m,ya),APP2V(pa,r,,-1))
42only 4 variables,initial array elements
43 Prod 1.Prod 2.Prod 3.Prod 4
4420202021202020212020202120202021
45Jan23.416.218.321.131.714.519.817.9
46Feb18.713.523.211.914.615.318.325.6
47Mar30.224.733.324.835.129.514.819.1
48
new ATJ 5
Cell Formulas
RangeFormula
D10,G10,G34,G27,G23,G19,K15,G15D10=FORMULATEXT(D11)
D11:E22D11=ATEXTSPLIT(B5:E7,"/")
G11:N13G11=ARESIZE(D11#,ROWS(B5:E7),COLUMNS(D11#)*COLUMNS(B5:E7))
G16:H16G16=ATEXTSPLIT(C3,"/")
K16K16=COLUMNS(G16#)
G20:M20G20=ATEXTSPLIT(ATEXTJOIN(B4:E4,REPT(",.",K16-1)&","))
G24:N24G24=INDEX(G16#,MOD(SEQUENCE(,COLUMNS(G11#))-1,2)+1)
G28:O31G28=AREPORT(G11#,G5:G7,G24#)
G35:O39G35=APP2V(G20#,G28#,,-1)
G43:O47G43=LET(ma,B5:E7,p,B4:E4,y,C3,m,A5:A7,ts,ATEXTSPLIT(ma,"/"),nm,ARESIZE(ts,ROWS(ma),COLUMNS(ts)*COLUMNS(ma)),ys,ATEXTSPLIT(y,"/"),cy,COLUMNS(ys),pa,ATEXTSPLIT(ATEXTJOIN(p,REPT(",.",cy-1)&",")),ya,INDEX(ys,MOD(SEQUENCE(,COLUMNS(nm))-1,cy)+1),r,AREPORT(nm,m,ya),APP2V(pa,r,,-1))
Dynamic array formulas.
 
Proof of how same formula updates dynamically, (no refresh ? ) for an expanded data set in all directions, one more year, one more product, one more month.
LAMBDA 1.1.2.xlsx
ABCDEFGHIJKLMNOPQRSTUVWX
1expanded data setsame single cell formula
2
3Report2019/2020/2021 Prod 1..Prod 2..Prod 3..Prod 4..Prod 5
4MonthProd 1Prod 2Prod 3Prod 4Prod 5201920202021201920202021201920202021201920202021201920202021
5Jan23.4/16.2/21.318.3/21.1/42.631.7/14.5/25.719.8/17.9/29.136.8/29.8/12.3Jan23.416.221.318.321.142.631.714.525.719.817.929.136.829.812.3
6Feb18.7/13.5/19.823.2/11.9/34.714.6/15.3/33.318.3/25.6/30.617.2/19.4/32.8Feb18.713.519.823.211.934.714.615.333.318.325.630.617.219.432.8
7Mar30.2/24.7/31.533.3/24.8/16.735.1/29.5/44.414.8/19.1/42.227.3/11.8/39.1Mar30.224.731.533.324.816.735.129.544.414.819.142.227.311.839.1
8Apr15.8/22.3/48.729.6/18.3/38.722.6/41.3/30.826.4/12.8/31.427.6/32.1/19.7Apr15.822.348.729.618.338.722.641.330.826.412.831.427.632.119.7
9
new ATJ 6
Cell Formulas
RangeFormula
H3:W8H3=LET(ma,B5:F8,p,B4:F4,y,C3,m,A5:A8,ts,ATEXTSPLIT(ma,"/"),nm,ARESIZE(ts,ROWS(ma),COLUMNS(ts)*COLUMNS(ma)),ys,ATEXTSPLIT(y,"/"),cy,COLUMNS(ys),pa,ATEXTSPLIT(ATEXTJOIN(p,REPT(",.",cy-1)&",")),ya,INDEX(ys,MOD(SEQUENCE(,COLUMNS(nm))-1,cy)+1),r,AREPORT(nm,m,ya),APP2V(pa,r,,-1))
Dynamic array formulas.
 
New function by Dermot, SPLITTER, using recursion. I salute his initiative for using recursion!! ✌?
Deals only with single values, no 1D or 2D arrays
For single values this is my take, no recursion SP(a,d)
Excel Formula:
=LAMBDA(a,d,LET(s,SEQUENCE(,LEN(a)+1),x,FILTER(s,(MID(d&a,s,1)=d)*s),y,FILTER(s,(MID(a&d,s,1)=d)*s),MID(a,x,y-x)))
Book1
ABCDEFGH
1Dermot's function SPLITTER
2
3=SPLITTER(B4:B5,",")=ATEXTSPLIT(B4:B5,",")
4a,b#NUM!ab
5c,dcd
6
7Seems function is designed only for single values
8
9=SPLITTER(B10,",")
10a,bab
11
12Variant for single values, no recursion SP(a,d)
13=SP(B14,",")
14a,bab
15
Sheet1
Cell Formulas
RangeFormula
D3,F3,D13,D9D3=FORMULATEXT(D4)
D4D4=SPLITTER(B4:B5,",")
F4:G5F4=ATEXTSPLIT(B4:B5,",")
D10:E10D10=SPLITTER(B10,",")
D14:E14D14=SP(B14,",")
Dynamic array formulas.
 
Task: Remove text between delimiters using combo ATEXTSPLIT/ATEXTJOIN
Inspired by latest YT (11-Nov-21) of MyOnlineTrainingHub. Power Query - Remove Text Between Delimiters Reusable Custom Function
ARBD(a,ld,rd,[kd]) Array Remove Between Delimiters. Calls ATEXTSPLIT , ATEXTJOIN
a: array 1D vertical
ld: left delimiter
rd: right delimiter
[kd]: keep delimiter: 0 or omitted, doesn't keep,1 or <>0, keeps delimiters

Excel Formula:
=LAMBDA(a,ld,rd,[kd],LET(d,"|",x,SUBSTITUTE(SUBSTITUTE(a,ld,IF(kd,ld&d,d)),rd,IF(kd,d&rd,d)),
    t,ATEXTSPLIT(x,d),c,INT(COLUMNS(t)/2)+1,y,INDEX(t,SEQUENCE(ROWS(a)),SEQUENCE(,c,,2)),
    ATEXTJOIN(y,"",1)
    )
)
LAMBDA 1.2.1.xlsx
ABCDEFG
1ld,"(",rd,")",kd,omittedld,"(",rd,")",kd,1
2=ARBD(A3:A4,"(",")")=ARBD(A3:A4,"(",")",1)
312(a),23(bc),456(cde)12,23,45612(),23(),456()
4ab(123),cde(12),f,gh(1234),(89),ijkab,cde,f,gh,,ijkab(),cde(),f,gh(),(),ijk
5
6ld,"(",rd,")",kd,omittedld,"(",rd,")",kd,1
7=ARBD(A8:A10,"(",")")=ARBD(A8:A10,"(",")",1)
8a(1),b(2),(3),(4),(5),c,(1234),da,b,,,,c,,da(),b(),(),(),(),c,(),d
91 (ab),2 (abc)1,21 (),2 ()
101234,56(uyuyluylyuttdtydiyt)781234,56781234,56()78
11
ATEXTSPLIT btwn delim
Cell Formulas
RangeFormula
C2,E2,C7,E7C2=FORMULATEXT(C3)
C3:C4C3=ARBD(A3:A4,"(",")")
E3:E4E3=ARBD(A3:A4,"(",")",1)
C8:C10C8=ARBD(A8:A10,"(",")")
E8:E10E8=ARBD(A8:A10,"(",")",1)
Dynamic array formulas.
 
Inspired by latest Excel Campus-Jon's latest YT (21-Apr-2022) : What is the Best Way to Split Text in Excel?
Using new functions TEXTSPLIT, TEXTBEFORE, TEXTAFTER
TEXTSPLIT-vs-TEXTBEFORE-AFTER.xlsx
ABCDEFGH
1Jon's formulas using TEXTBEFORE, TEXTAFTER
2Split Three or More Names with TEXTBEFORE & TEXTAFTER
3
4Full NameFirstMiddleLastMiddle Part 1Middle Part 2Middle Part 3
5Ardisj FlindallArdisj FlindallFlindall#VALUE! 
6Nixie FairbrotherNixie FairbrotherFairbrother#VALUE! 
7Ciro Acres BarabischCiroAcresBarabischAcres BarabischAcresAcres
8Malinda Ann Howton O'KerinMalindaAnn HowtonO'KerinAnn Howton O'KerinAnn HowtonAnn Howton
9Melisse GasnollMelisse GasnollGasnoll#VALUE! 
10Booth McMylorBooth McMylorMcMylor#VALUE! 
11Rafi Walesa PriddisRafiWalesaPriddisWalesa PriddisWalesaWalesa
12Anita Mulvey SerrelsAnitaMulveySerrelsMulvey SerrelsMulveyMulvey
13Gillian FordGillian FordFord#VALUE! 
14Aldo HandscombeAldo HandscombeHandscombe#VALUE! 
15
16Alternative formulas:
17
18Full NameFirstMiddleLast
19Ardisj FlindallArdisj Flindall
20Nixie FairbrotherNixie Fairbrother
21Ciro Acres BarabischCiro Acres Barabisch
22Malinda Ann Howton O'KerinMalinda Ann Howton O'Kerin
23Melisse GasnollMelisse Gasnoll
24Booth McMylorBooth McMylor
25Rafi Walesa PriddisRafi Walesa Priddis
26Anita Mulvey SerrelsAnita Mulvey Serrels
27Gillian FordGillian Ford
28Aldo HandscombeAldo Handscombe
29
30First:=TAKE(TEXTSPLIT([@[Full Name]]," "),,1)
31Middle:=SUBSTITUTE(SUBSTITUTE([@[Full Name]],[@First],""),[@Last],"")
32Last:=TAKE(TEXTSPLIT([@[Full Name]]," "),,-1)
33
34Full NameFirstMiddleLast
35Ardisj FlindallArdisj Flindall
36Nixie FairbrotherNixie Fairbrother
37Ciro Acres BarabischCiroAcresBarabisch
38Malinda Ann Howton O'KerinMalindaAnn HowtonO'Kerin
39Melisse GasnollMelisse Gasnoll
40Booth McMylorBooth McMylor
41Rafi Walesa PriddisRafiWalesaPriddis
42Anita Mulvey SerrelsAnitaMulveySerrels
43Gillian FordGillian Ford
44Aldo HandscombeAldo Handscombe
45
46alternative
47Middle:=IFERROR(TEXTJOIN(" ",,DROP(DROP(TEXTSPLIT([@[Full Name]]," "),,1),,-1)),"")
48
Split 3 Names Table
Cell Formulas
RangeFormula
B5:B14B5=TEXTBEFORE([@[Full Name]]," ")
C5:C14C5=IFERROR(TEXTBEFORE(TEXTAFTER([@[Full Name]]," ")," ",-1),"")
D5:D14D5=TEXTAFTER([@[Full Name]]," ",-1)
E5:E14E5=TEXTAFTER([@[Full Name]]," ")
F5:F14F5=TEXTBEFORE([@[Middle Part 1]]," ",-1)
G5:G14G5=IFERROR([@[Middle Part 2]],"")
B19:B28,B35:B44B19=TAKE(TEXTSPLIT([@[Full Name]]," "),,1)
C19:C28C19=SUBSTITUTE(SUBSTITUTE([@[Full Name]],[@First],""),[@Last],"")
D19:D28,D35:D44D19=TAKE(TEXTSPLIT([@[Full Name]]," "),,-1)
B30B30=FORMULATEXT(B19)
B31,B47B31=FORMULATEXT(C19)
B32B32=FORMULATEXT(D19)
C35:C44C35=IFERROR(TEXTJOIN(" ",,DROP(DROP(TEXTSPLIT([@[Full Name]]," "),,1),,-1)),"")
 
A quick function to split a vertical array "ar" into 3 parts by a delimiter "dl" (1st part-before delimiter,2nd part-btw delimiters, 3rd part-after delimiter)
ATEXTBTW(ar,dl)
Excel Formula:
=LAMBDA(ar, dl,
    LET(
        s, " ",
        a, TRIM(SUBSTITUTE(ar, dl, s)),
        MAKEARRAY(
            ROWS(a),
            3,
            LAMBDA(r, c,
                LET(
                    i, INDEX(a, r),
                    x, IFERROR(TEXTBEFORE(i, s, 1), i),
                    y, IFERROR(TEXTAFTER(i, s, -1), ""),
                    SWITCH(c, 1, x, 3, y, TRIM(SUBSTITUTE(SUBSTITUTE(i, x, ""), y, "")))
                )
            )
        )
    )
)
TEXTSPLIT-vs-TEXTBEFORE-AFTER.xlsx
ABCDEFGHIJ
1Array Splitting in 3.ATEXTBTW functiondl," "checking LEN after splitting
2=ATEXTBTW(A3:A12," ")=LEN(C3#)
3Ardisj FlindallArdisjFlindall608
4Nixie FairbrotherNixieFairbrother5011
5Ciro Acres BarabischCiroAcresBarabisch459
6Malinda Ann Howton O'KerinMalindaAnn HowtonO'Kerin7107
7Melisse GasnollMelisseGasnoll707
8Booth McMylorBoothMcMylor507
9Rafi Walesa PriddisRafiWalesaPriddis467
10Anita Mulvey SerrelsAnitaMulveySerrels567
11Gillian FordGillianFord704
12Aldo HandscombeAldoHandscombe4010
13
14dl," "
15=ATEXTBTW(A16:A20," ")=LEN(C16#)
16aa bb cc dd ee ffaabb cc dd eeff2112
17xx yyxxyy202
18ggg ggg300
19h i j k l m n ohi j k l m no1111
20asd hgf daasdhgfda332
21
22dl,", " (dbl delimiter "," plus a space " ")
23=ATEXTBTW(A24:A28,", ")=LEN(C24#)
24aa, bb, cc, dd, ee, ffaabb cc dd eeff2112
25xx, yyxxyy202
26gggggg300
27h, i, j, k, l, m, n, ohi j k l m no1111
28asd, hgf, daasdhgfda332
29
30dl,","
31sample with extra spaces=ATEXTBTW(A32:A35,",")=LEN(C32#)
32aa , bb, cc ,ddaabb ccdd252
33eee , ffeeeff302
34gggg200
35hh , kl , mnohhklmno223
36
ATEXTBTW
Cell Formulas
RangeFormula
C2,G31,C31,G23,C23,G15,C15,G2C2=FORMULATEXT(C3)
C3:E12C3=ATEXTBTW(A3:A12," ")
G3:I12,G32:I35,G24:I28,G16:I20G3=LEN(C3#)
C16:E20C16=ATEXTBTW(A16:A20," ")
C24:E28C24=ATEXTBTW(A24:A28,", ")
C32:E35C32=ATEXTBTW(A32:A35,",")
Dynamic array formulas.
 
Great new challenge from Chandoo, today's YT (19May22) : Excel Challenge - Can you split their expenses?
Chandoo solved this brilliantly with a PQ table and a bunch of formulas for the final report.
To solve this with only a single cell formula, no PQ, no refresh, no helper anything there are 3 different approaches:
1st: does not call any other custom-made functions (has some limitations though)
2nd: solution, calls ATEXTSPLIT (no limitations)
3rd: solution, calls SPILLBYROW, function under ASCAN thread, will be published there, link will follow when will be ready (no limitations).
split-expenses.xlsx
ABCDEFGH
1sample table: "exp"Task: Getting from table values to this report
2
3Expense DetailsPersonHow much they spentShare of ExpensesTo Receive / Pay
4Phil: 255.12,121.29,160.23Phil4928.882982.4351946.445
5Alan: 43.17,226.76,343.66,358.01Alan2723.082982.435-259.355
6Phil: 159.95,177.56,278.37Stu1961.672982.435-1020.765
7Stu: 206.51,188.09,244.68,33.21,152.98Doug2316.112982.435-666.325
8Phil: 285.91,306.4,140.68
9Doug: 226.76,226.76,169.6,208.67↑↑↑↑↑↑↑↑↑↑↑↑↑↑↑↑
10Phil: 326.4unq namessum of expensessum(clm2)/4clm2-clm3
11Phil: 308.43,224.95,102.33
12Phil: 168.64
13Stu: 259.93
14Stu: 121.29
15Stu: 177
16Alan: 172.23
17Alan: 214.04,162.58,205.66,188.16,128.41
18Alan: 62.75,160.51,173.34,283.8
19Phil: 356.3,361.34,41.35,255.94,67.42
20Stu: 168.25,161.28,248.45
21Doug: 163.93,308.43,218.58
22Phil: 226.04,265.97,140.81,197.45
23Doug: 216.79,180.39,246.65,149.55
24
25
new ATEXTSPLIT 1
 
1st solution. Concept. Why we have limitations.
split-expenses.xlsx
ABCDEFGHIJKLMNOPQRST
1Concept 1st solution approach:
2
3TEXTSPLIT still does not handle arrays, but can be tricked to do it, with some limitations.
4
5TEXTSPLIT array will deliver
6only the first cells columnCell by cell works fine
7=TEXTSPLIT(B8:B9,",")
8a,b,caabc=TEXTSPLIT(B8,",")
9x,yxxy=TEXTSPLIT(B9,",")
10
11Trick to make TEXTSPLIT "work" with arrays step by step:Previous step delivers an extra row
12that we have to exclude
13=B14:B15&":"=TEXTJOIN("",,D14#)=TEXTSPLIT(F14,",",":")=DROP(I14#,-1)=IFNA(M14#,"")
14a,b,ca,b,c:a,b,c:x,y:abcabcabc
15x,yx,y:↑↑↑↑xy#N/Axy#N/Axy
16↑↑↑↑#N/A#N/A
17↑↑↑↑
18Entire array in a single cell, therefore the limitations
19of joining limit of 32767 chars.
20Can not be used for large arrays !!!!!
21
22trick single cell formula
23=LET(a,B14:B15,b,TEXTJOIN("",,a&":"),c,TEXTSPLIT(b,",",":"),IFNA(DROP(c,-1),""))
24abc
25xy
26
new ATEXTSPLIT 2
Cell Formulas
RangeFormula
D7,D23,Q13,D13,F13,I13,M13D7=FORMULATEXT(D8)
D8:D9D8=TEXTSPLIT(B8:B9,",")
G8:I8,G9:H9G8=TEXTSPLIT(B8,",")
J8:J9J8=FORMULATEXT(G8)
D14:D15D14=B14:B15&":"
F14F14=TEXTJOIN("",,D14#)
I14:K16I14=TEXTSPLIT(F14,",",":")
M14:O15M14=DROP(I14#,-1)
Q14:S15Q14=IFNA(M14#,"")
D24:F25D24=LET(a,B14:B15,b,TEXTJOIN("",,a&":"),c,TEXTSPLIT(b,",",":"),IFNA(DROP(c,-1),""))
Dynamic array formulas.
 

Forum statistics

Threads
1,215,324
Messages
6,124,249
Members
449,149
Latest member
mwdbActuary

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