Baseball lineup (Index Match)

white84

New Member
Joined
May 11, 2018
Messages
40
Office Version
  1. 365
Platform
  1. Windows
I'm sure this will be easy for one of you. I'm close, need a final tweak.
I have a table of kids names with batting order in column1 (B3:B16), Inning # in row1 (C2:H2) and position they are playing each inning (1B, 2B, SS, etc.) scattered throughout the table.

I'd like to create a unique cell for each fielding position, and be able to change a separate drop-down selector for the inning (in B18), and have the kids name populate in that cell. 1st inning is working, but not when I try to expand beyond the first column. Do I need to convert to an array?

=INDEX($B$3:$B$16,MATCH("LF",$C$3:$C$16,0),MATCH($B$18,$C$2:$H$2,0))

Batting Order1st Inning2nd Inning3rd Inning4th Inning5th Inning6th Inning
HudsonLCFSS3BPP
BradleySSLCFSS1B
AJPP3B1BSS
KahlCCPP3B
BrantleyRF2BRCF2B
Griffin2BCCLCF
Rowdy1B1BRFCC
Liam3B1B1B3B
LucasRCF3BLFSS
ElijahRCFSS2BLF
JosiahRFLF2BLCF
GavinLFLCFRFRF
DaneLFRCFLFRCF
Kasen2BRCFLCFRF

1683128378068.png
 

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
What version of Excel are you using?

I suggest that you update your Account details (or click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)
 
Upvote 0
TRY THIS:
mr excel questions 33.xlsm
ABCDEFGH
1Batting Order1st Inning2nd Inning3rd Inning4th Inning5th Inning6th Inning
2HudsonLCFSS3BPP
3BradleySSLCFSS1B
4AJPP3B1BSS
5KahlCCPP3B
6BrantleyRF2BRCF2B
7Griffin2BCCLCF
8Rowdy1B1BRFCC
9Liam3B1B1B3B
10LucasRCF3BLFSS
11ElijahRCFSS2BLF
12JosiahRFLF2BLCF
13GavinLFLCFRFRF
14DaneLFRCFLFRCF
15Kasen2BRCFLCFRF
16
17Inning:3
18GavinKasen
19
20
21JosiahRowdy
22ElijahBrantley
23
24HudsonLiam
25Kahl
26
27
28
29Griffin
30
31
32
33
White84
Cell Formulas
RangeFormula
D18D18=INDEX($A$2:$A$15,MATCH("LCF",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
F18F18=INDEX($A$2:$A$15,MATCH("RCF",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
B21B21=INDEX($A$2:$A$15,MATCH("LF",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
H21H21=INDEX($A$2:$A$15,MATCH("RF",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
D22D22=INDEX($A$2:$A$15,MATCH("SS",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
F22F22=INDEX($A$2:$A$15,MATCH("2B",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
C24C24=INDEX($A$2:$A$15,MATCH("3B",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
G24G24=INDEX($A$2:$A$15,MATCH("1B",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
E25E25=INDEX($A$2:$A$15,MATCH("P",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
E29E29=INDEX($A$2:$A$15,MATCH("C",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
Cells with Data Validation
CellAllowCriteria
B17List1,2,3,4,5,6
 
Upvote 0
Solution
Thanks for updating your profile, another option is
Excel Formula:
=FILTER($A$2:$A$15,INDEX($B$2:$G$15,,MATCH($B$18,$B$1:$G$1,0))="LF")
 
Upvote 0
TRY THIS:
mr excel questions 33.xlsm
ABCDEFGH
1Batting Order1st Inning2nd Inning3rd Inning4th Inning5th Inning6th Inning
2HudsonLCFSS3BPP
3BradleySSLCFSS1B
4AJPP3B1BSS
5KahlCCPP3B
6BrantleyRF2BRCF2B
7Griffin2BCCLCF
8Rowdy1B1BRFCC
9Liam3B1B1B3B
10LucasRCF3BLFSS
11ElijahRCFSS2BLF
12JosiahRFLF2BLCF
13GavinLFLCFRFRF
14DaneLFRCFLFRCF
15Kasen2BRCFLCFRF
16
17Inning:3
18GavinKasen
19
20
21JosiahRowdy
22ElijahBrantley
23
24HudsonLiam
25Kahl
26
27
28
29Griffin
30
31
32
33
White84
Cell Formulas
RangeFormula
D18D18=INDEX($A$2:$A$15,MATCH("LCF",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
F18F18=INDEX($A$2:$A$15,MATCH("RCF",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
B21B21=INDEX($A$2:$A$15,MATCH("LF",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
H21H21=INDEX($A$2:$A$15,MATCH("RF",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
D22D22=INDEX($A$2:$A$15,MATCH("SS",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
F22F22=INDEX($A$2:$A$15,MATCH("2B",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
C24C24=INDEX($A$2:$A$15,MATCH("3B",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
G24G24=INDEX($A$2:$A$15,MATCH("1B",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
E25E25=INDEX($A$2:$A$15,MATCH("P",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
E29E29=INDEX($A$2:$A$15,MATCH("C",INDEX($B$2:$G$15,,MATCH($B$17,LEFT($B$1:$G$1,1)*1,0)),0))
Cells with Data Validation
CellAllowCriteria
B17List1,2,3,4,5,6
That works! Thank you!
 
Upvote 0
I'm happy that worked for you. But it is using short form for inning and some unnecessary functions because of that.
Here is a little cleaner version, and @Fluff 's version is very clean.

mr excel questions 33.xlsm
ABCDEFGH
1Batting Order1st Inning2nd Inning3rd Inning4th Inning5th Inning6th Inning
2HudsonLCFSS3BPP
3BradleySSLCFSS1B
4AJPP3B1BSS
5KahlCCPP3B
6BrantleyRF2BRCF2B
7Griffin2BCCLCF
8Rowdy1B1BRFCC
9Liam3B1B1B3B
10LucasRCF3BLFSS
11ElijahRCFSS2BLF
12JosiahRFLF2BLCF
13GavinLFLCFRFRF
14DaneLFRCFLFRCF
15Kasen2BRCFLCFRF
16
17Inning:
183rd InningGavinKasen
19
20JosiahRowdy
21ElijahBrantley
22
23HudsonLiam
24Kahl
25
26
27
28Griffin
29
30
White84
Cell Formulas
RangeFormula
D18D18=INDEX($B$2:$B$15,MATCH("LCF",INDEX($C$2:$H$15,,MATCH($B$18,$C$1:$H$1,0)),0))
F18F18=INDEX($B$2:$B$15,MATCH("RCF",INDEX($C$2:$H$15,,MATCH($B$18,$C$1:$H$1,0)),0))
B20B20=INDEX($B$2:$B$15,MATCH("LF",INDEX($C$2:$H$15,,MATCH($B$18,$C$1:$H$1,0)),0))
H20H20=INDEX($B$2:$B$15,MATCH("RF",INDEX($C$2:$H$15,,MATCH($B$18,$C$1:$H$1,0)),0))
D21D21=INDEX($B$2:$B$15,MATCH("SS",INDEX($C$2:$H$15,,MATCH($B$18,$C$1:$H$1,0)),0))
F21F21=INDEX($B$2:$B$15,MATCH("2B",INDEX($C$2:$H$15,,MATCH($B$18,$C$1:$H$1,0)),0))
C23C23=INDEX($B$2:$B$15,MATCH("3B",INDEX($C$2:$H$15,,MATCH($B$18,$C$1:$H$1,0)),0))
G23G23=INDEX($B$2:$B$15,MATCH("1B",INDEX($C$2:$H$15,,MATCH($B$18,$C$1:$H$1,0)),0))
E24E24=INDEX($B$2:$B$15,MATCH("P",INDEX($C$2:$H$15,,MATCH($B$18,$C$1:$H$1,0)),0))
E28E28=INDEX($B$2:$B$15,MATCH("C",INDEX($C$2:$H$15,,MATCH($B$18,$C$1:$H$1,0)),0))
Cells with Data Validation
CellAllowCriteria
B18List=$C$1:$H$1




Best wishes!
 
Upvote 0
Glad we could help & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,223,879
Messages
6,175,148
Members
452,615
Latest member
bogeys2birdies

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