Having Trouble with VLOOKUP where Multiple Rows of Data Have Value VLOOKUP Is Referencing

Aimee S.

Board Regular
Joined
Sep 28, 2010
Messages
236
Office Version
  1. 365
Platform
  1. Windows
Happy Friday Folks.

Any ideas? I have data (as an example) that looks like this:

Cust. # SVC
2400001 KSBAS
2400001 K2B10
2400001 K2RES
2400001 K2TPD

<colgroup><col><col><col></colgroup><tbody>
</tbody>

On another sheet I am trying to figure out how to make it look like this in a single row:

Cust.
# SVC 1SVC 2SVC 3SVC 4
2400001 KSBASK2B10K2RESK2TPD

<colgroup><col><col><col><col><col></colgroup><tbody>
</tbody>

Such that the formulas in SVC 1 SVC 2 SVC 3 SVC 4 etc. know to pull in the value "KSBAS" into the SVC 1 column since it is the first value to appear in the SVC column on the source sheet for that customer # 2400001, and have the subsequent SVC 2 SVC 3 and SVC 4 etc columns know to continue to pull in the next SVC value that appears for that customer # on the source sheet until the customer ID changes.

Any help is appreciated! I am guessing INDEX may have something to do with it but I am sorely inexperienced with INDEX related formulas. :(
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
maybe something like,,,,

Unknown
ABCDE
1Cust. #SVC
22400001KSBAS
32400001K2B10
42400001K2RES
52400001K2TPD
6
72400001KSBASK2B10K2RESK2TPD

<tbody>
</tbody>
Sheet2

Array Formulas
CellFormula
B7{=IFERROR(INDEX($C$2:$C$5,SMALL(IF($A$2:$A$5=$A7,ROW($A$2:$A$5)-ROW($A$2)+1),COLUMNS($A7:A7))),"")}

<tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>
 
Upvote 0
I think this is very close. It isn't working (erroring out) but that is probably because I am not applying correctly.

=IFERROR(INDEX('Customer Services'!$C$2:$C$2000,SMALL(IF('Customer Services'!$A$2:$A$2000=$A3,ROW('Customer Services'!$A$2:$A$2000)-ROW('Customer Services'!$A$2)+1),COLUMNS($A3:A3))),"") with CTRL SHFT ENTER

I uploaded images of the source and target worksheets

https://imgur.com/IjRg2tT

https://imgur.com/NcqbVjT

The cells highlighted in red on the Dashboard worksheet are where the formulas will live, and the worksheet entitled Customer Services is where the data is being pulled from.:( Thanks for your help!!










maybe something like,,,,

Unknown
A
B
C
D
E
1
Cust. #
SVC
2
2400001
KSBAS
3
2400001
K2B10
4
2400001
K2RES
5
2400001
K2TPD
6
7
2400001
KSBAS
K2B10
K2RES
K2TPD

<tbody>
</tbody>
Sheet2


Array Formulas
Cell
Formula
B7
{=IFERROR(INDEX($C$2:$C$5,SMALL(IF($A$2:$A$5=$A7,ROW($A$2:$A$5)-ROW($A$2)+1),COLUMNS($A7:A7))),"")}

<tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>
 
Upvote 0

Forum statistics

Threads
1,215,477
Messages
6,125,031
Members
449,205
Latest member
Eggy66

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