INDEX(MATCH) or something like that

strangedenial

New Member
Joined
Sep 15, 2014
Messages
39
Hi all,

I know it is so easy to do but I guess I can not ask the right question to dear friend Google so I can not find the right answer. So here I am.

What I want to do is below, please help.

Thanks in advance!

ClientsService 1Service 2Service 3
AAAEnlglishSpanish
BBBItalianEnglishSpanish
CCCSpanish
DDDEnglishItalian
EEESpanishEnglish
FFFItalian
GGGEnglish

<tbody>
</tbody>

that was the clients and services table, and the result I want is :

Results 1Results 2
CLIENTS FOR ENGLISHCLIENTS FOR SPANISH
AAAAAA
BBBBBB
DDDCCC
EEEEEE
GGG

<tbody>
</tbody>

I hope showing was more understandable than explaining in words.


Thanks for any help
 

Some videos you may like

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092
Welcome to MrExcel.

Formula in F2 copied down and across:

<b>Excel 2010</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #BBB"><colgroup><col width="25px" style="background-color: #DAE7F5" /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #DAE7F5;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style=";">Clients</td><td style=";">Service 1</td><td style=";">Service 2</td><td style=";">Service 3</td><td style="text-align: right;;"></td><td style=";">English</td><td style=";">Spanish</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">AAA</td><td style=";">English</td><td style=";">Spanish</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">AAA</td><td style=";">AAA</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">BBB</td><td style=";">Italian</td><td style=";">English</td><td style=";">Spanish</td><td style="text-align: right;;"></td><td style=";">BBB</td><td style=";">BBB</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">CCC</td><td style=";">Spanish</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">DDD</td><td style=";">CCC</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">DDD</td><td style=";">English</td><td style=";">Italian</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">EEE</td><td style=";">EEE</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style=";">EEE</td><td style=";">Spanish</td><td style=";">English</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">GGG</td><td style=";"></td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style=";">FFF</td><td style=";">Italian</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";"></td><td style=";"></td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style=";">GGG</td><td style=";">English</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";"></td><td style=";"></td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #BBB;border-top:none;text-align: center;background-color: #DAE7F5;color: #161120">Sheet1</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Array Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #BBB"><thead><tr style=" background-color: #DAE7F5;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">F2</th><td style="text-align:left">{=IFERROR(<font color="Blue">INDEX(<font color="Red">$A$2:$A$8,SMALL(<font color="Green">IF(<font color="Purple">ISNUMBER(<font color="Teal">SEARCH(<font color="#FF00FF">F$1,$B$2:$D$8</font>)</font>),ROW(<font color="Teal">$B$2:$D$8</font>)-ROW(<font color="Teal">$B$2</font>)+1</font>),ROWS(<font color="Purple">F$2:F2</font>)</font>)</font>),""</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br />
 

strangedenial

New Member
Joined
Sep 15, 2014
Messages
39
Ok one more detail I fotgot;

I have some clients who take enligsh for 2 persons, so for them Service 1 and Service 2 show both english.
So this formula writes that client's name twice.

How not to duplicate the same client if they have 2 or more same services ?

Thanks!
 

squirrel31

New Member
Joined
Sep 15, 2014
Messages
30

ADVERTISEMENT

This formula should highlight the row/rows you don't need (Providing you do it in Conditional Formatting). Then all you would need to do is filter by colour and remove any duplicated records.

=COUNTIF($A$2:A2,A2)>1
 

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092
How about?

=IFERROR(INDEX($A$2:$A$8,SMALL(IF((ISNUMBER(SEARCH(F$1,$B$2:$B$8))+ISNUMBER(SEARCH(F$1,$C$2:$C$8))+ISNUMBER(SEARCH(F$1,$D$2:$D$8))),ROW($B$2:$D$8)-ROW($B$2)+1),ROWS(F$2:F2))),"")

confirmed with Ctrl+Shift+Enter.
 

Watch MrExcel Video

Forum statistics

Threads
1,122,370
Messages
5,595,764
Members
414,017
Latest member
surajks

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
Top