Index and Match ??? Help needed

dtwyford

New Member
Joined
Dec 24, 2015
Messages
14
Good day everyone. I could use some guidance. I have table that is used for people to pick dates they want to volunteer their time for. I need to translate the date

from
Date 1Date 2Date 3Date 4Date 5Date 6
Bob
xxx
Sue
xxx
John
xxx
Frank
xxx
Mary
xxx
Gail
xxx
Keith
xxx
Glenda
xxx

<tbody>
</tbody>

to
Person 1Person 2Person 3Person 4
Date 1
Sue
Frank
Gail
Glenda
Date 2
Date 3
Date 4
Date 5

Date 6

<colgroup><col style="width:48pt" width="64" span="5"> </colgroup><tbody>
</tbody>

I am looking for a dynamic formula for the "TO" table. Any thoughts?

D
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
Copy cell L3 to all other cells in the Range(L3:O8).


Excel 2010
KLMNO
1Person 1Person 2Person 3Person 4
2SueFrankGailGlenda
3Date 1xxxx
4Date 2xx
5Date 3xx
6Date 4x
7Date 5xx
8Date 6x

<colgroup><col style="width: 25pxpx"><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
L3=IF(INDEX($B$3:$G$10,MATCH(L$2,$A$3:$A$10,0),MATCH($K3,$B$2:$G$2,0))="x","x","")

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>
 
Upvote 0
Jim,

Thanks, but not quite. The green names are an example of what I want the "TO" table to look like.
The "FROM" Tables top row is the dates, the left most column are the names, the cells under and to the right are the various selections I need to translate / pivot into the "TO" table.
Any tweaks you can recommend?
D

Worksheet Formulas
CellFormula
L3=IF(INDEX($B$3:$G$10,MATCH(L$2,$A$3:$A$10,0),MATCH($K3,$B$2:$G$2,0))="x","x","")

<tbody>
</tbody>

<tbody>
</tbody>
[/QUOTE]
 
Upvote 0
To accomplish the bringing over of the Names I am unable to do it in using a formula. But I can via VBA.
So here's the (Standard Module) Code.

Rich (BB code):
Sub EliminateBlankRowsWhenCopying()
lr = Range("B" & Rows.Count).End(xlUp).Row 'Your from table Date 1 Column
Set Rng = Range("B3:B" & lr)
Application.Calculation = xlCalculationManual
    Rng.SpecialCells(xlCellTypeConstants).Offset(0, -1).Copy
    Worksheets("Sheet1").Range("L2").PasteSpecial Paste:=xlPasteAll, Operation:=xlNone, Transpose:=True
Application.Calculation = xlCalculationAutomatic
End Sub
 
Upvote 0
With a formula


Excel 2013/2016
ABCDEFGHIJKLMN
1Date 1Date 2Date 3Date 4Date 5Date 6Person 1Person 2Person 3Person 4
2BobxxxDate 1SueFrankGailGlenda
3SuexxxDate 2SueFrankMaryKeith
4JohnxxxDate 3BobJohnGailGlenda
5FrankxxxDate 4BobSueMaryKeith
6MaryxxxDate 5JohnFrankKeithGlenda
7GailxxxDate 6BobJohnMaryGail
8Keithxxx
9Glendaxxx
Appendix
Cell Formulas
RangeFormula
K2=IFERROR(INDEX($A$2:$A$9,AGGREGATE(15,6,ROW($A$2:$A$9)-ROW($A$2)+1/(($B$1:$G$1=$J2)*($B$2:$G$9="x")),COLUMNS($A:A))),"")
 
Upvote 0
Jim ,Thank you.
Darren




To accomplish the bringing over of the Names I am unable to do it in using a formula. But I can via VBA.
So here's the (Standard Module) Code.

Rich (BB code):
Sub EliminateBlankRowsWhenCopying()
lr = Range("B" & Rows.Count).End(xlUp).Row 'Your from table Date 1 Column
Set Rng = Range("B3:B" & lr)
Application.Calculation = xlCalculationManual
    Rng.SpecialCells(xlCellTypeConstants).Offset(0, -1).Copy
    Worksheets("Sheet1").Range("L2").PasteSpecial Paste:=xlPasteAll, Operation:=xlNone, Transpose:=True
Application.Calculation = xlCalculationAutomatic
End Sub
 
Upvote 0
You're welcome & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,254
Members
448,556
Latest member
peterhess2002

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