Retriving multiple items

gwizrus

New Member
Joined
Sep 26, 2006
Messages
12
I have a ss with server listings and drive zones associated with them. I need to find all the drives shared for a given server and drive zone.

The input values would be Server and drive zone. For instance, if I search for plums and 4,1. Output for Shared With would be apples, carrots.
tape report.xls
ABCDEFGHIJ
1DriveZone
2Server4,04,14,25,05,1
3applesxxServerDriveZoneSharedWith
4plumsxapples4,1plums,carrots
5carrotsxx
Sheet1


Thanks
 

Some videos you may like

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

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,201
If you download and install the morefunc.xll add-in...

J4:

=SUBSTITUTE(TRIM(IF(INDEX($B$3:$F$5,MATCH(H4,$A$3:$A$5,0),MATCH(I4,$B$2:$F$2,0))="x",MCONCAT(IF(SETV(INDEX($B$3:$F$5,0,MATCH(I4,$B$2:$F$2,0)))="x",IF($A$3:$A$5=H4,"",$A$3:$A$5),"")," "),""))," ",",")

which you need to confirm with control+shift+enter, not just with enter.
 

gwizrus

New Member
Joined
Sep 26, 2006
Messages
12
Aladin,

That was impressive!!! Now, being an excel newbie with functions, I need to figure out if I can understand it.

Thanks again.
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,201
Aladin,

That was impressive!!! Now, being an excel newbie with functions, I need to figure out if I can understand it.

Thanks again.

You are welcome. Remove the SETV call though...

=SUBSTITUTE(TRIM(IF(INDEX($B$3:$F$5,MATCH(H4,$A$3:$A$5,0),MATCH(I4,$B$2:$F$2,0))="x",MCONCAT(IF(INDEX($B$3:$F$5,0,MATCH(I4,$B$2:$F$2,0))="x",IF($A$3:$A$5=H4,"",$A$3:$A$5),"")," "),""))," ",",")
 

gwizrus

New Member
Joined
Sep 26, 2006
Messages
12

ADVERTISEMENT

Aladin,

Thanks, I actually figured out I did not need it since a getv was never referenced. Otherwise it served no other purpose.

I have two questions. What causes excel to loop through the values. I'm use to doing Do..While or something to that nature to cause a loop in code. Second looking at this part of the code....

IF($A$3:$A$5=H4,"",$A$3:$A$5)

How does excel know to correlate the correct A cell with the row of x's that were found. My understanding is that by using a 0 for the row number in the index function causes an array containing only the values for that column? is this correct?

Thanks,
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,201
...
I have two questions. What causes excel to loop through the values. I'm use to doing Do..While or something to that nature to cause a loop in code. Second looking at this part of the code....

IF($A$3:$A$5=H4,"",$A$3:$A$5)

How does excel know to correlate the correct A cell with the row of x's that were found. My understanding is that by using a 0 for the row number in the index function causes an array containing only the values for that column? is this correct?
...

Let's look at the main IF in MCONCAT...

Code:
IF(INDEX($B$3:$F$5,0,MATCH(I4,$B$2:$F$2,0))="x",
      IF($A$3:$A$5=H4,"",$A$3:$A$5),
      "")

The Index epression in the Condition-part of the main (outer) IF picks out all cells corresponding to the drive zone of interest and each such cell is tested for being equal to "x". For every TRUE evaluation, the inner IF, that is,

Code:
IF($A$3:$A$5=H4,
    "",
    $A$3:$A$5)

otherwise (for a FALSE evaluation) we get a blank (i.e., "").

The Condition-part of the outer IF yields

{TRUE;TRUE;TRUE}

The Condition-part of the inner IF which is:

$A$3:$A$5=H4

corresponding to the foregoing set of TRUE's yields:

{TRUE;FALSE;FALSE}

meaning

A3=H4 (apples=apples)
A4=H4 (plums=apples)
A5=H4 (carrots=apples)

with TRUE return "", otherwise (with FALSE) return corresponding A-cell. Thus, the Inner If yields:

{"";"plums";"carrots"}

a result passed to MCONCAT to process.

Hope this answers your question.
 

gwizrus

New Member
Joined
Sep 26, 2006
Messages
12
Aladin,

Thanks a bunch. Things are starting to make sense. Your explaination was very usefull.
 

Watch MrExcel Video

Forum statistics

Threads
1,114,042
Messages
5,545,688
Members
410,698
Latest member
Wloven
Top