Forum Discussion
Dependant Dropdown Using Dynamic Arrays
- May 15, 2022
What you try to generate in G10 that's array of array which is not supported by Excel, at least directly. There are different, but similar, techniques for workarounds. As variant, in your case it could be
=LET( clients, UNIQUE(Table1[Client Name]), totalClients, ROWS(clients), holderName, LAMBDA(clientName,holders,clients, TRANSPOSE(FILTER(holders, clients=clientName)) ), fakeArray, LAMBDA(array, LAMBDA(array)), arrayOfFakeArrays, MAP( clients, LAMBDA(client, fakeArray( holderName( client, Table1[Holder Name], Table1[Client Name])))), result, MAKEARRAY( totalClients,9, LAMBDA(row,col, LET(getRow, INDEX(arrayOfFakeArrays,row,1)(), INDEX(getRow,1,col)))), IFERROR( result, "") )You can't use arrays in data validation list, only ranges. More exactly references on them.
What you try to generate in G10 that's array of array which is not supported by Excel, at least directly. There are different, but similar, techniques for workarounds. As variant, in your case it could be
=LET(
clients, UNIQUE(Table1[Client Name]),
totalClients, ROWS(clients),
holderName, LAMBDA(clientName,holders,clients,
TRANSPOSE(FILTER(holders, clients=clientName)) ),
fakeArray, LAMBDA(array, LAMBDA(array)),
arrayOfFakeArrays, MAP( clients,
LAMBDA(client,
fakeArray( holderName( client, Table1[Holder Name], Table1[Client Name])))),
result, MAKEARRAY( totalClients,9,
LAMBDA(row,col,
LET(getRow, INDEX(arrayOfFakeArrays,row,1)(),
INDEX(getRow,1,col)))),
IFERROR( result, "")
)
You can't use arrays in data validation list, only ranges. More exactly references on them.
Most of the things you do, seems like magic to me 🙂
Do allow me sometime to grasp the solution. You got my respect !
Thanks a Lot !
Can LAMBDA be used to produce the result in all the columns Including Unique Client List in First Column ?
Regards
Kanwaljit
- SergeiBaklanMay 15, 2022Diamond Contributor
Yes, you may add it as first column making resulting array:
=LET( clients, UNIQUE(Table1[Client Name]), totalClients, ROWS(clients), holderName, LAMBDA(clientName,holders,clients, TRANSPOSE(FILTER(holders, clients=clientName)) ), fakeArray, LAMBDA(array, LAMBDA(array)), arrayOfFakeArrays, MAP( clients, LAMBDA(client, fakeArray( holderName( client, Table1[Holder Name], Table1[Client Name])))), result, MAKEARRAY( totalClients, 10, LAMBDA(row,col, LET(getRow, INDEX(arrayOfFakeArrays,row,1)(), IF( col=1, INDEX( clients, 1), INDEX( getRow, 1, col-1 ) ) ) ) ), IFERROR( result, "") )- KanwalNo1May 15, 2022Iron Contributor
The latest formula is working, but the First column contains only "India 01" in all the rows instead of Unique Client Names.
- SergeiBaklanMay 16, 2022Diamond Contributor
Sorry for the misprint. Corrected in attached file.