How to extract matching data to rows using formula

Dhinakaran

Board Regular
Joined
Mar 30, 2016
Messages
54
Office Version
  1. 365
  2. 2021
  3. 2016
Platform
  1. Windows
Hello,

I've a data of State and its cities where states are repeated while the cities are unique where I need to extract the unique cities in rows from column AJ to AP against the respective state as shown in the sample below.

Book2
AHAIAJAKALAMANAOAP
3StateCityStateCity 1City 2City 3City 4
4AlabamaAkronAlabama
5ArizonaAlpineArizona
6CaliforniaAgoura HillsCalifornia
7ColoradoApplewoodColorado
8FloridaApollo BeachFlorida
9GeorgiaAlstonGeorgia
10HawaiiEwa GentryHawaii
11IndianaBoonvilleIndiana
12KentuckyWorthingtonKentucky
13WashingtonYarrow PointWashington
14AlabamaAlexandria
15ArizonaArizona Village
16CaliforniaAlderpoint
17ColoradoWoodland Park
18FloridaAve Maria
19GeorgiaAmbrose
20HawaiiEast Honolulu
21IndianaBoswell
22KentuckyWoodland Hills
23WashingtonWollochet
24AlabamaAshville
25ArizonaBeyerville
26CaliforniaAllendale
27ColoradoWilliamsburg
28FloridaBay Hill
29GeorgiaAppling
30HawaiiBlack Sands
31IndianaBridgeton
32KentuckyWilliamstown
33WashingtonWaterville
34AlabamaX
35ArizonaY
36CaliforniaZ
Sheet2
Cell Formulas
RangeFormula
AL4:AL13AL4=UNIQUE(AH4:AH33)
Dynamic array formulas.



TIA.
 

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
Is this what you want?

24 08 18.xlsm
AHAIAJAKALAMANAOAP
3StateCityStateCity 1City 2City 3City 4
4AlabamaAkronAlabamaAkronAlexandriaAshvilleX
5ArizonaAlpineArizonaAlpineArizona VillageBeyervilleY
6CaliforniaAgoura HillsCaliforniaAgoura HillsAlderpointAllendaleZ
7ColoradoApplewoodColoradoApplewoodWoodland ParkWilliamsburg
8FloridaApollo BeachFloridaApollo BeachAve MariaBay Hill
9GeorgiaAlstonGeorgiaAlstonAmbroseAppling
10HawaiiEwa GentryHawaiiEwa GentryEast HonoluluBlack Sands
11IndianaBoonvilleIndianaBoonvilleBoswellBridgeton
12KentuckyWorthingtonKentuckyWorthingtonWoodland HillsWilliamstown
13WashingtonYarrow PointWashingtonYarrow PointWollochetWaterville
14AlabamaAlexandria
15ArizonaArizona Village
16CaliforniaAlderpoint
17ColoradoWoodland Park
18FloridaAve Maria
19GeorgiaAmbrose
20HawaiiEast Honolulu
21IndianaBoswell
22KentuckyWoodland Hills
23WashingtonWollochet
24AlabamaAshville
25ArizonaBeyerville
26CaliforniaAllendale
27ColoradoWilliamsburg
28FloridaBay Hill
29GeorgiaAppling
30HawaiiBlack Sands
31IndianaBridgeton
32KentuckyWilliamstown
33WashingtonWaterville
34AlabamaX
35ArizonaY
36CaliforniaZ
Cities
Cell Formulas
RangeFormula
AL4:AL13AL4=UNIQUE(AH4:AH33)
AM7:AO13,AM4:AP6AM4=TRANSPOSE(FILTER(AI$4:AI$36,AH$4:AH$36=AL4))
Dynamic array formulas.
 
Upvote 0
Solution
Is this what you want?

24 08 18.xlsm
AHAIAJAKALAMANAOAP
3StateCityStateCity 1City 2City 3City 4
4AlabamaAkronAlabamaAkronAlexandriaAshvilleX
5ArizonaAlpineArizonaAlpineArizona VillageBeyervilleY
6CaliforniaAgoura HillsCaliforniaAgoura HillsAlderpointAllendaleZ
7ColoradoApplewoodColoradoApplewoodWoodland ParkWilliamsburg
8FloridaApollo BeachFloridaApollo BeachAve MariaBay Hill
9GeorgiaAlstonGeorgiaAlstonAmbroseAppling
10HawaiiEwa GentryHawaiiEwa GentryEast HonoluluBlack Sands
11IndianaBoonvilleIndianaBoonvilleBoswellBridgeton
12KentuckyWorthingtonKentuckyWorthingtonWoodland HillsWilliamstown
13WashingtonYarrow PointWashingtonYarrow PointWollochetWaterville
14AlabamaAlexandria
15ArizonaArizona Village
16CaliforniaAlderpoint
17ColoradoWoodland Park
18FloridaAve Maria
19GeorgiaAmbrose
20HawaiiEast Honolulu
21IndianaBoswell
22KentuckyWoodland Hills
23WashingtonWollochet
24AlabamaAshville
25ArizonaBeyerville
26CaliforniaAllendale
27ColoradoWilliamsburg
28FloridaBay Hill
29GeorgiaAppling
30HawaiiBlack Sands
31IndianaBridgeton
32KentuckyWilliamstown
33WashingtonWaterville
34AlabamaX
35ArizonaY
36CaliforniaZ
Cities
Cell Formulas
RangeFormula
AL4:AL13AL4=UNIQUE(AH4:AH33)
AM7:AO13,AM4:AP6AM4=TRANSPOSE(FILTER(AI$4:AI$36,AH$4:AH$36=AL4))
Dynamic array formulas.

Exactly right. I missed to use the filter clause. Thanks much Peter_SSs
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,176
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