Lambda and spill array - Addresses and postal codes

Phantom1

New Member
Joined
Sep 26, 2018
Messages
24
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Hello friends.
I have a table who has a column of addresses and in another column their corresponding postal codes. I need a dynamic array formula that lives in a single cell and spills out every unique postal code in a row and below each postal code all the addresses associated.
Thanks in advance for any response.
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
How about
Excel Formula:
=LET(u,UNIQUE(FILTER(A2:A10000,A2:A10000<>"")),m,MAX(COUNTIFS(A:A,u)),DROP(REDUCE("",u,LAMBDA(x,y,HSTACK(x,VSTACK(y,EXPAND(FILTER(B2:B10000,A2:A10000=y),m,,""))))),,1))
 
Upvote 0
Solution
One possibility could be:

Excel Formula:
=LET(
    arr, TRANSPOSE(DROP(GROUPBY(Table1[Postal Code],Table1[Address],HSTACK(LAMBDA(v,TEXTJOIN("|",0,"",v,"")),ROWS),0,0),1)),
    a, CHOOSEROWS(arr,2),
    p, TAKE(arr,1),
    r, TAKE(arr,-1),
    n, MAX(r),
    VSTACK(p,TEXTBEFORE(TEXTAFTER(a&REPT("|",n-r),"|",SEQUENCE(n)),"|"))
)

Adjust the row_fields and values arguments of the GROUPBY function as needed (replace Table1[Postal Code] and Table1[Address] to reflect your actual table/range references).
 
Last edited:
Upvote 0
The usual suspects again😊.
Excellent work guys.
Thanks again for sharing your knowledge. Both work just fine and sure better than my attempts.
Cheers!
 
Upvote 0
Glad we could help & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,224,819
Messages
6,181,153
Members
453,021
Latest member
Justyna P

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