Mapping Data Dependent Unique List

sfsteve002

Board Regular
Joined
Apr 10, 2011
Messages
114
Hi,

I have a workbook which contains the Channel Data Set in Column H and Sub Channel in Column M. I want to create a to be able to enter a Channel Name into cell A1 and Column B to show a unique list mapped to A1.

Any help on this would be greatly appreciated!
 

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
Hi,

I have a workbook which contains the Channel Data Set in Column H and Sub Channel in Column M. I want to create a to be able to enter a Channel Name into cell A1 and Column B to show a unique list mapped to A1.

Any help on this would be greatly appreciated!

Care to post 8 rows from column H and column M along with the desired results?
 
Upvote 0
Here's the sample data set.

<table border="0" cellpadding="0" cellspacing="0" width="307"><col style="mso-width-source:userset;mso-width-alt:5339;width:110pt" width="146"> <col style="mso-width-source:userset;mso-width-alt:5888;width:121pt" width="161"> <tbody><tr style="height:15.0pt" height="20"> <td style="height:15.0pt;width:110pt" height="20" width="146">Commission Junction</td> <td style="width:121pt" width="161">Engagement</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Commission Junction</td> <td>Engagement</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Commission Junction</td> <td>Engagement</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Email</td> <td>Newsletter</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Email</td> <td>Newsletter</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Homepage</td> <td>Transactional</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Homepage</td> <td>Homepage</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Email</td> <td>welcome</td> </tr> </tbody></table>
 
Upvote 0
Here's the sample data set.

<TABLE border=0 cellSpacing=0 cellPadding=0 width=307><COLGROUP><COL style="WIDTH: 110pt; mso-width-source: userset; mso-width-alt: 5339" width=146><COL style="WIDTH: 121pt; mso-width-source: userset; mso-width-alt: 5888" width=161><TBODY><TR style="HEIGHT: 15pt" height=20><TD style="WIDTH: 110pt; HEIGHT: 15pt" height=20 width=146>Commission Junction</TD><TD style="WIDTH: 121pt" width=161>Engagement</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="HEIGHT: 15pt" height=20>Commission Junction</TD><TD>Engagement</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="HEIGHT: 15pt" height=20>Commission Junction</TD><TD>Engagement</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="HEIGHT: 15pt" height=20>Email</TD><TD>Newsletter</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="HEIGHT: 15pt" height=20>Email</TD><TD>Newsletter</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="HEIGHT: 15pt" height=20>Homepage</TD><TD>Transactional</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="HEIGHT: 15pt" height=20>Homepage</TD><TD>Homepage</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="HEIGHT: 15pt" height=20>Email</TD><TD>welcome</TD></TR></TBODY></TABLE>

Great. Must the value in A1 hold for column H or M?
 
Upvote 0
H on the left set of Values.

Thanks!

<TABLE style="WIDTH: 291pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=386><COLGROUP><COL style="WIDTH: 64pt; mso-width-source: userset; mso-width-alt: 3015" width=85><COL style="WIDTH: 38pt; mso-width-source: userset; mso-width-alt: 1792" width=50><COL style="WIDTH: 109pt; mso-width-source: userset; mso-width-alt: 5148" width=145><COL style="WIDTH: 80pt; mso-width-source: userset; mso-width-alt: 3783" width=106><TBODY><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; WIDTH: 64pt; HEIGHT: 14.4pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=19 width=85>Email</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; WIDTH: 38pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" id=td_post_2917318 class=xl65 width=50> </TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; WIDTH: 109pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 width=145>Channel Data</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; WIDTH: 80pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 width=106>SubChannel</TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=19 align=right>2</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65> </TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Commission Junction</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Engagement</TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl66 height=19>List</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65> </TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Commission Junction</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Engagement</TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=19>Newsletter</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65> </TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Commission Junction</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Engagement</TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=19>welcome</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65> </TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Email</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Newsletter</TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=19> </TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65> </TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Email</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Newsletter</TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=19> </TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65> </TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Homepage</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Transactional</TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=19> </TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65> </TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Homepage</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Homepage</TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=19> </TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65> </TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>Email</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>welcome</TD></TR></TBODY></TABLE>

Most of the in-between columns are not shown here.

Channel Data is in H2:H9 and SubChannel in M2:M9.

A1: Email

A2, control+shift+enter, not just enter:
Rich (BB code):
=SUM(IF(FREQUENCY(IF(M2:M9<>"",IF(H2:H9=A1,
    MATCH("~"&M2:M9,M2:M9&"",0))),ROW(M2:M9)-ROW(M2)+1),1))

A3: List

A4, control+shift+enter, not just enter, and copy down:
Rich (BB code):
=IF(ROWS($A$4:A4)<=$A$2,INDEX($M$2:$M$9,
  SMALL(IF(FREQUENCY(IF($M$2:$M$9<>"",IF($H$2:$H$9=$A$1,
   MATCH("~"&$M$2:$M$9,$M$2:$M$9&"",0))),
    ROW($M$2:$M$9)-ROW($M$2)+1),ROW($M$2:$M$9)-ROW($M$2)+1),
     ROWS($A$4:A4))),"")

The above formulas can be shortened up by naming the ranges.

Let Sheet1 house the data (Adjust to suit).

Define CHANNEL by means of Insert | Name | Define or Formulas | Name Manager as referring to:
Rich (BB code):
=Sheet1!$H$2:$H$9

SubCHANNEL as referring to:
Rich (BB code):
=Sheet1!$M$2:$M$9

And Ivec as referring to:
Rich (BB code):
=ROW(CHANNEL)-ROW(INDEX(CHANNEL,1,1))+1

If done properly, the formulas would become:

A2, control+shift+enter, not just enter:
Rich (BB code):
=SUM(IF(FREQUENCY(IF(SubCHANNEL<>"",IF(CHANNEL=A1,
  MATCH("~"&SubCHANNEL,SubCHANNEL&"",0))),Ivec),1))

A4, control+shift+enter, not just enter, and copy down:
Rich (BB code):
=IF(ROWS($A$4:A4)<=$A$2,INDEX(SubCHANNEL,
  SMALL(IF(FREQUENCY(IF(SubCHANNEL<>"",IF(CHANNEL=$A$1,
   MATCH("~"&SubCHANNEL,SubCHANNEL&"",0))),Ivec),Ivec),
    ROWS($A$4:A4))),"")
 
Upvote 0

Forum statistics

Threads
1,214,515
Messages
6,119,974
Members
448,934
Latest member
audette89

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