APPENDNHV

=APPENDNHV(ai,a,hv,i)

ai
first array or initial array
a
group of arrays between () (array1,array2,...,arrayN)
hv
string for direction, only "h" or "v"
i
index, ignored,0 or 1 appends ai to the whole group of arrays, i>1 indexes inside the group arrays a

APPENDNHV appends N arrays horizontally or vertically.

Xlambda

Well-known Member
Joined
Mar 8, 2021
Messages
860
Office Version
  1. 365
Platform
  1. Windows
APPENDNHV !! recursive !! appends N arrays horizontally or vertically , calls the other 2 recursive APPEND2H and APPEND2V .
Uses the second syntax of INDEX, INDEX(reference, row_num, [column_num], [area_num]) , so carrys its restrictions (reference argument instead of arrays, arrays should be in the same spreadsheet).
It is a single formula for both directions and for that has an extra argument hv . If you want to eliminate this and have instead 2 separate formulas , use these ones:
APPENDNH(ai,a,i)=LAMBDA(ai,a,i,LET(k,AREAS(a),j,MAX(i,1),IF(j=k+1,ai,APPENDNH(APPEND2H(ai,INDEX(a,,,j),),a,j+1))))
APPENDNV(ai,a,i)=LAMBDA(ai,a,i,LET(k,AREAS(a),j,MAX(i,1),IF(j=k+1,ai,APPENDNV(APPEND2V(ai,INDEX(a,,,j),),a,j+1)))) also recursive ofcourse.
Excel Formula:
=LAMBDA(ai,a,hv,i,
    LET(k,AREAS(a),
       x,OR(hv={"h","v"}),j,MAX(i,1),
       IF(j=k+1,IF(x,ai,"''h''or''v''only"),APPENDNHV(IF(hv="h",APPEND2H(ai,INDEX(a,,,j),),APPEND2V(ai,INDEX(a,,,j),)),a,hv,j+1))
   )
)
LAMBDA 5.0.xlsm
ABCDEFGHIJKLMNOP
1a1 - 1a1 - 2a2 - 1a2 - 2a3 - 1a3 - 2a3 - 3a4 - 1a4 - 2a5 - 1a5 - 2
2a1 - 3a1 - 4a2 - 3a2 - 4a3 - 4a3 - 5a3 - 6a4 - 3a4 - 4a5 - 3a5 - 4
3a1 - 5a1 - 6a4 - 5a4 - 6a5 - 5a5 - 6
4a4 - 7a4 - 8a5 - 7a5 - 8
5
6=APPENDNHV(A1#,(D1#,G1#,K1#,N1#),"h",)
7a1 - 1a1 - 2a2 - 1a2 - 2a3 - 1a3 - 2a3 - 3a4 - 1a4 - 2a5 - 1a5 - 2
8a1 - 3a1 - 4a2 - 3a2 - 4a3 - 4a3 - 5a3 - 6a4 - 3a4 - 4a5 - 3a5 - 4
9a1 - 5a1 - 6a4 - 5a4 - 6a5 - 5a5 - 6
10a4 - 7a4 - 8a5 - 7a5 - 8
11
12i=3=APPENDNHV(A1#,(D1#,G1#,K1#,N1#),"h",3)=APPENDNHV(SEQUENCE(4,,"17-03-21"),(D1#,G1#,K1#,N1#),"h",3)
13a1 - 1a1 - 2a4 - 1a4 - 2a5 - 1a5 - 217-03-21a4 - 1a4 - 2a5 - 1a5 - 2
14a1 - 3a1 - 4a4 - 3a4 - 4a5 - 3a5 - 418-03-21a4 - 3a4 - 4a5 - 3a5 - 4
15a1 - 5a1 - 6a4 - 5a4 - 6a5 - 5a5 - 619-03-21a4 - 5a4 - 6a5 - 5a5 - 6
16a4 - 7a4 - 8a5 - 7a5 - 820-03-21a4 - 7a4 - 8a5 - 7a5 - 8
17
18=APPENDNHV(A1#,(D1#,G1#,K1#,N1#),"v",)=APPENDNHV("Clm-"&SEQUENCE(,2),(D1#,G1#,K1#,N1#),"v",3)
19a1 - 1a1 - 2Clm-1Clm-2
20a1 - 3a1 - 4a4 - 1a4 - 2
21a1 - 5a1 - 6i=3a4 - 3a4 - 4
22a2 - 1a2 - 2=APPENDNHV(A1#,(D1#,G1#,K1#,N1#),"v",3)a4 - 5a4 - 6
23a2 - 3a2 - 4a1 - 1a1 - 2a4 - 7a4 - 8
24a3 - 1a3 - 2a3 - 3a1 - 3a1 - 4a5 - 1a5 - 2
25a3 - 4a3 - 5a3 - 6a1 - 5a1 - 6a5 - 3a5 - 4
26a4 - 1a4 - 2a4 - 1a4 - 2a5 - 5a5 - 6
27a4 - 3a4 - 4a4 - 3a4 - 4a5 - 7a5 - 8
28a4 - 5a4 - 6a4 - 5a4 - 6
29a4 - 7a4 - 8a4 - 7a4 - 8
30a5 - 1a5 - 2a5 - 1a5 - 2
31a5 - 3a5 - 4a5 - 3a5 - 4
32a5 - 5a5 - 6a5 - 5a5 - 6
33a5 - 7a5 - 8a5 - 7a5 - 8
34
AAPPENDH
Cell Formulas
RangeFormula
A1:B3A1="a1 - "&SEQUENCE(3,2)
D1:E2D1="a2 - "&SEQUENCE(2,2)
G1:I2G1="a3 - "&SEQUENCE(2,3)
K1:L4K1="a4 - "&SEQUENCE(4,2)
N1:O4N1="a5 - "&SEQUENCE(4,2)
A6,E22,A18,I12A6=FORMULATEXT(A7)
A7:K10A7=APPENDNHV(A1#,(D1#,G1#,K1#,N1#),"h",)
B12B12=FORMULATEXT(A13)
A13:F16A13=APPENDNHV(A1#,(D1#,G1#,K1#,N1#),"h",3)
I13:M16I13=APPENDNHV(SEQUENCE(4,,"17-03-21"),(D1#,G1#,K1#,N1#),"h",3)
I18I18=FORMULATEXT(K19)
A19:C33A19=APPENDNHV(A1#,(D1#,G1#,K1#,N1#),"v",)
K19:L27K19=APPENDNHV("Clm-"&SEQUENCE(,2),(D1#,G1#,K1#,N1#),"v",3)
E23:F33E23=APPENDNHV(A1#,(D1#,G1#,K1#,N1#),"v",3)
Dynamic array formulas.
 
Upvote 0

Forum statistics

Threads
1,223,933
Messages
6,175,471
Members
452,646
Latest member
tudou

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