Index/Match appropriate here?

Reboshua

Board Regular
Joined
Jan 23, 2015
Messages
88
The more I use excel, the more I realize how little I know.

- In the grid below, you can see the names of baseball players in columns B-J.
- In columns AG-AO, you can see the players' positions.

My task is to come up with a formula for AP-AX that will put the players in the assigned order of row 1: P | C1B | 2B etc....

Here's the rub - there's an extra person that needs to fit into the "Utility" spot (Column AX) and I have no idea how to tell excel to map these guys to their positions and whatever is leftover, toss that in the UTIL column.

How do you do that?

Thank you in advance!

Excel 2016 (Windows) 64 bit
[TABLE="class: head"]
<tbody>[TR="bgcolor: #E0E0F0"]
[TH][/TH]
[TH]
B
[/TH]
[TH]
C
[/TH]
[TH]
D
[/TH]
[TH]
E
[/TH]
[TH]
F
[/TH]
[TH]
G
[/TH]
[TH]
H
[/TH]
[TH]
I
[/TH]
[TH]
J
[/TH]
[TH]
AG
[/TH]
[TH]
AH
[/TH]
[TH]
AI
[/TH]
[TH]
AJ
[/TH]
[TH]
AK
[/TH]
[TH]
AL
[/TH]
[TH]
AM
[/TH]
[TH]
AN
[/TH]
[TH]
AO
[/TH]
[TH]
AP
[/TH]
[TH]
AQ
[/TH]
[TH]
AR
[/TH]
[TH]
AS
[/TH]
[TH]
AT
[/TH]
[TH]
AU
[/TH]
[TH]
AV
[/TH]
[TH]
AW
[/TH]
[TH]
AX
[/TH]
[/TR]
[TR="bgcolor: #FFFFFF"]
[TD="bgcolor: #E0E0F0"]
1
[/TD]
[TD="bgcolor: #4472C4"]P1[/TD]
[TD="bgcolor: #4472C4"]P2[/TD]
[TD="bgcolor: #4472C4"]P3[/TD]
[TD="bgcolor: #4472C4"]P4[/TD]
[TD="bgcolor: #4472C4"]P5[/TD]
[TD="bgcolor: #4472C4"]P6[/TD]
[TD="bgcolor: #4472C4"]P7[/TD]
[TD="bgcolor: #4472C4"]P8[/TD]
[TD="bgcolor: #4472C4"]Pitcher[/TD]
[TD="bgcolor: #4472C4"]POS1[/TD]
[TD="bgcolor: #4472C4"]POS2[/TD]
[TD="bgcolor: #4472C4"]POS3[/TD]
[TD="bgcolor: #4472C4"]POS4[/TD]
[TD="bgcolor: #4472C4"]POS5[/TD]
[TD="bgcolor: #4472C4"]POS6[/TD]
[TD="bgcolor: #4472C4"]POS7[/TD]
[TD="bgcolor: #4472C4"]POS8[/TD]
[TD="bgcolor: #4472C4"]POS9[/TD]
[TD="bgcolor: #4472C4"]P[/TD]
[TD="bgcolor: #4472C4"]C1B[/TD]
[TD="bgcolor: #4472C4"]2B[/TD]
[TD="bgcolor: #4472C4"]3B[/TD]
[TD="bgcolor: #4472C4"]SS[/TD]
[TD="bgcolor: #4472C4"]OF[/TD]
[TD="bgcolor: #4472C4"]OF2[/TD]
[TD="bgcolor: #4472C4"]OF3[/TD]
[TD="bgcolor: #4472C4"]UTIL[/TD]
[/TR]
[TR="bgcolor: #FFFFFF"]
[TD="bgcolor: #E0E0F0"]
2
[/TD]
[TD="bgcolor: #FFFF00"]Kole Calhoun[/TD]
[TD="bgcolor: #FFFF00"]Shohei Ohtani[/TD]
[TD="bgcolor: #FFFF00"]Justin Upton[/TD]
[TD="bgcolor: #FFFF00"]David Fletcher[/TD]
[TD="bgcolor: #FFFF00"]Starling Marte[/TD]
[TD="bgcolor: #FFFF00"]David Freese[/TD]
[TD="bgcolor: #FFFF00"]Francisco Cervelli[/TD]
[TD="bgcolor: #FFFF00"]Jordy Mercer[/TD]
[TD="bgcolor: #FFFF00"]Nick Pivetta[/TD]
[TD="bgcolor: #D9E1F2"]OF[/TD]
[TD="bgcolor: #D9E1F2"]OF[/TD]
[TD="bgcolor: #D9E1F2"]OF[/TD]
[TD="bgcolor: #D9E1F2"]2B[/TD]
[TD="bgcolor: #D9E1F2"]OF[/TD]
[TD="bgcolor: #D9E1F2"]3B[/TD]
[TD="bgcolor: #D9E1F2"]C1B[/TD]
[TD="bgcolor: #D9E1F2"]SS[/TD]
[TD="bgcolor: #D9E1F2"]P[/TD]
[TD="bgcolor: #D9E1F2"][/TD]
[TD="bgcolor: #D9E1F2"][/TD]
[TD="bgcolor: #D9E1F2"][/TD]
[TD="bgcolor: #D9E1F2"][/TD]
[TD="bgcolor: #D9E1F2"][/TD]
[TD="bgcolor: #D9E1F2"][/TD]
[TD="bgcolor: #D9E1F2"][/TD]
[TD="bgcolor: #D9E1F2"][/TD]
[TD="bgcolor: #D9E1F2"][/TD]
[/TR]
[TR="bgcolor: #FFFFFF"]
[TD="bgcolor: #E0E0F0"]
3
[/TD]
[TD="bgcolor: #FFFF00"]Shohei Ohtani[/TD]
[TD="bgcolor: #FFFF00"]Justin Upton[/TD]
[TD="bgcolor: #FFFF00"]Eric Young Jr.[/TD]
[TD="bgcolor: #FFFF00"]Kaleb Cowart[/TD]
[TD="bgcolor: #FFFF00"]Gregory Polanco[/TD]
[TD="bgcolor: #FFFF00"]Josh Harrison[/TD]
[TD="bgcolor: #FFFF00"]Francisco Cervelli[/TD]
[TD="bgcolor: #FFFF00"]Jordy Mercer[/TD]
[TD="bgcolor: #FFFF00"]Zack Greinke[/TD]
[TD]OF[/TD]
[TD]OF[/TD]
[TD]OF[/TD]
[TD]3B[/TD]
[TD]OF[/TD]
[TD]2B[/TD]
[TD]C1B[/TD]
[TD]SS[/TD]
[TD]P[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
 
Last edited:

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Any thoughts on this one, friends? Even if you can't solve, some idea of level of effort or how to think about this?
 
Upvote 0
Maybe:

ABCDEFGHIAGAHAIAJAKALAMANAOAPAQARASATAUAVAWAX

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
[TD="align: center"]1[/TD]
[TD="bgcolor: #4472C4"]P1[/TD]
[TD="bgcolor: #4472C4"]P2[/TD]
[TD="bgcolor: #4472C4"]P3[/TD]
[TD="bgcolor: #4472C4"]P4[/TD]
[TD="bgcolor: #4472C4"]P5[/TD]
[TD="bgcolor: #4472C4"]P6[/TD]
[TD="bgcolor: #4472C4"]P7[/TD]
[TD="bgcolor: #4472C4"]P8[/TD]
[TD="bgcolor: #4472C4"]Pitcher[/TD]
[TD="bgcolor: #4472C4"]POS1[/TD]
[TD="bgcolor: #4472C4"]POS2[/TD]
[TD="bgcolor: #4472C4"]POS3[/TD]
[TD="bgcolor: #4472C4"]POS4[/TD]
[TD="bgcolor: #4472C4"]POS5[/TD]
[TD="bgcolor: #4472C4"]POS6[/TD]
[TD="bgcolor: #4472C4"]POS7[/TD]
[TD="bgcolor: #4472C4"]POS8[/TD]
[TD="bgcolor: #4472C4"]POS9[/TD]
[TD="bgcolor: #4472C4"]P[/TD]
[TD="bgcolor: #4472C4"]C1B[/TD]
[TD="bgcolor: #4472C4"]2B[/TD]
[TD="bgcolor: #4472C4"]3B[/TD]
[TD="bgcolor: #4472C4"]SS[/TD]
[TD="bgcolor: #4472C4"]OF[/TD]
[TD="bgcolor: #4472C4"]OF[/TD]
[TD="bgcolor: #4472C4"]OF[/TD]
[TD="bgcolor: #4472C4"]UTIL[/TD]

[TD="align: center"]2[/TD]
[TD="bgcolor: #FFFF00"]Kole Calhoun[/TD]
[TD="bgcolor: #FFFF00"]Shohei Ohtani[/TD]
[TD="bgcolor: #FFFF00"]Justin Upton[/TD]
[TD="bgcolor: #FFFF00"]David Fletcher[/TD]
[TD="bgcolor: #FFFF00"]Starling Marte[/TD]
[TD="bgcolor: #FFFF00"]David Freese[/TD]
[TD="bgcolor: #FFFF00"]Francisco Cervelli[/TD]
[TD="bgcolor: #FFFF00"]Jordy Mercer[/TD]
[TD="bgcolor: #FFFF00"]Nick Pivetta[/TD]
[TD="bgcolor: #D9E1F2"]OF[/TD]
[TD="bgcolor: #D9E1F2"]OF[/TD]
[TD="bgcolor: #D9E1F2"]OF[/TD]
[TD="bgcolor: #D9E1F2"]2B[/TD]
[TD="bgcolor: #D9E1F2"]OF[/TD]
[TD="bgcolor: #D9E1F2"]3B[/TD]
[TD="bgcolor: #D9E1F2"]C1B[/TD]
[TD="bgcolor: #D9E1F2"]SS[/TD]
[TD="bgcolor: #D9E1F2"]P[/TD]
[TD="bgcolor: #D9E1F2"]Nick Pivetta[/TD]
[TD="bgcolor: #D9E1F2"]Francisco Cervelli[/TD]
[TD="bgcolor: #D9E1F2"]David Fletcher[/TD]
[TD="bgcolor: #D9E1F2"]David Freese[/TD]
[TD="bgcolor: #D9E1F2"]Jordy Mercer[/TD]
[TD="bgcolor: #D9E1F2"]Kole Calhoun[/TD]
[TD="bgcolor: #D9E1F2"]Shohei Ohtani[/TD]
[TD="bgcolor: #D9E1F2"]Justin Upton[/TD]
[TD="bgcolor: #D9E1F2"]Starling Marte[/TD]

[TD="align: center"]3[/TD]
[TD="bgcolor: #FFFF00"]Shohei Ohtani[/TD]
[TD="bgcolor: #FFFF00"]Justin Upton[/TD]
[TD="bgcolor: #FFFF00"]Eric Young Jr.[/TD]
[TD="bgcolor: #FFFF00"]Kaleb Cowart[/TD]
[TD="bgcolor: #FFFF00"]Gregory Polanco[/TD]
[TD="bgcolor: #FFFF00"]Josh Harrison[/TD]
[TD="bgcolor: #FFFF00"]Francisco Cervelli[/TD]
[TD="bgcolor: #FFFF00"]Jordy Mercer[/TD]
[TD="bgcolor: #FFFF00"]Zack Greinke[/TD]
[TD="bgcolor: #FFFFFF"]OF[/TD]
[TD="bgcolor: #FFFFFF"]OF[/TD]
[TD="bgcolor: #FFFFFF"]OF[/TD]
[TD="bgcolor: #FFFFFF"]3B[/TD]
[TD="bgcolor: #FFFFFF"]OF[/TD]
[TD="bgcolor: #FFFFFF"]2B[/TD]
[TD="bgcolor: #FFFFFF"]C1B[/TD]
[TD="bgcolor: #FFFFFF"]SS[/TD]
[TD="bgcolor: #FFFFFF"]P[/TD]
[TD="bgcolor: #D9E1F2"]Zack Greinke[/TD]
[TD="bgcolor: #D9E1F2"]Francisco Cervelli[/TD]
[TD="bgcolor: #D9E1F2"]Josh Harrison[/TD]
[TD="bgcolor: #D9E1F2"]Kaleb Cowart[/TD]
[TD="bgcolor: #D9E1F2"]Jordy Mercer[/TD]
[TD="bgcolor: #D9E1F2"]Shohei Ohtani[/TD]
[TD="bgcolor: #D9E1F2"]Justin Upton[/TD]
[TD="bgcolor: #D9E1F2"]Eric Young Jr.[/TD]
[TD="bgcolor: #D9E1F2"]Gregory Polanco[/TD]

</tbody>
Sheet2

[TABLE="width: 85%"]
<tbody>[TR]
[TD]Array Formulas[TABLE="width: 100%"]
<thead>[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]
[TH="width: 10px"]Cell[/TH]
[TH="align: left"]Formula[/TH]
[/TR]
</thead><tbody>[TR]
[TH="width: 10px, bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]AP2[/TH]
[TD="align: left"]{=IFERROR(INDEX($A2:$J2,SMALL(IF($AG2:$AO2=AP$1,COLUMN($AG2:$AO2)-COLUMN($AG2)+1),COUNTIF($AP$1:AP$1,AP$1))),INDEX($A2:$I2,MIN(IF(COUNTIF($AO2:AO2,$A2:$I2)=0,COLUMN($A2:$I2)-COLUMN($A2)+1))))}[/TD]
[/TR]
</tbody>[/TABLE]
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself[/TD]
[/TR]
</tbody>[/TABLE]

Drag down and to the right.

Note that I changed OF1 OF2 OF3 to just OF OF OF. Also, I see that the order of the positions in rows 2 and 3 are the same. If they never change, you can just use formulas like =A2, =F2, etc.
 
Upvote 0
Eric - thank you - that worked perfectly. The positions do change quite drastically when you have more sets, so this is super useful.

Best,

David
 
Upvote 0

Forum statistics

Threads
1,224,521
Messages
6,179,280
Members
452,902
Latest member
Knuddeluff

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