2D Array Lookup

ajat5142

New Member
Joined
Jul 5, 2019
Messages
3
Hi,

I am new here. The question I am asking may have a solution in a previous thread. If so, please share a link to it. Really appreciate it.

[TABLE="width: 500"]
<tbody>[TR]
[TD][/TD]
[TD]A[/TD]
[TD]B[/TD]
[TD]C[/TD]
[TD]D[/TD]
[TD]E[/TD]
[TD]F[/TD]
[TD]G[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]Date[/TD]
[TD]Cashier A[/TD]
[TD]Cashier B[/TD]
[TD]Cashier C[/TD]
[TD][/TD]
[TD]Max[/TD]
[TD]182[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]1-Jan[/TD]
[TD]164[/TD]
[TD]156[/TD]
[TD]157[/TD]
[TD][/TD]
[TD]Cashier[/TD]
[TD]xx[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]2-Jan[/TD]
[TD]182[/TD]
[TD]159[/TD]
[TD]158[/TD]
[TD][/TD]
[TD]Date[/TD]
[TD]yy[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]3-Jan[/TD]
[TD]172[/TD]
[TD]102[/TD]
[TD]180[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

How can I get the 'xx' & 'yy' to return 'Cashier A' & 2-Jan?

Thank you.
AJ
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
Hi,

There is a strong chance that I have overthought this and someone will comeup with a simpler solution but here it is:


Book1
ABCDEFG
1DateCashier ACashier BCashier CMax200
21-Jan164156157CashierCashier B
32-Jan182200158Date2-Jan
43-Jan172102180
Sheet1
Cell Formulas
RangeFormula
G1=MAX($B$2:$D$4)
G2{=INDEX($B$1:$D$1,SMALL(IF(MMULT({1,1,1},--($B$2:$D$4=$G$1)),COLUMN($B$2:$D$2)-COLUMN($B$2)+1),1))}
G3{=INDEX($A$2:$A$4,SMALL(IF(INDEX($B$2:$D$4,,MATCH($G$2,$B$1:$D$1,0))=$G$1,ROW($A$2:$A$4)-ROW($A$2)+1),1))}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Last edited:
Upvote 0
Hi Aryatect,

I am basically jumping up and down now. That was amazing. I do envy the logical build behind the whole formula. Thank you so much.:bow:
 
Upvote 0
I think below may be a better formula to list duplicates too:


Book1
ABCDEFGHI
1DateCashier ACashier BCashier CMax200Max Count2
21-Jan200156157CashierCashier ACashier B
32-Jan182200158Date3-Jan2-Jan
43-Jan172102180
Sheet7
Cell Formulas
RangeFormula
I1=COUNTIF($B$2:$D$4,G1)
G1=LARGE($B$2:$D$4,1)
G3=IFERROR(INDEX($A$2:$A$4,MATCH($G$1,INDEX($B$2:$D$4,,MATCH(G$2,$B$1:$D$1,0)))),"")
G2{=IF(COLUMNS($G$2:G2)>$I$1,"",INDEX($B$1:$D$1,AGGREGATE(15,6,(COLUMN($B$2:$D$2)-COLUMN($B$2)+1)/($B$2:$D$4=$G$1),COLUMNS($G$2:G2))))}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
If you only want to work on a single maximum:

<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:40.87px;" /><col style="width:76.04px;" /><col style="width:78.89px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td><td >G</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Date</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Cashier A</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Cashier B</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Cashier C</td><td > </td><td style="background-color:#ccc0da; ">Max</td><td style="background-color:#ffff00; text-align:right; ">199</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >1-Jan</td><td style="text-align:right; ">164</td><td style="text-align:right; ">156</td><td style="text-align:right; ">157</td><td > </td><td style="background-color:#ccc0da; ">Cashier</td><td >Cashier C</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >2-Jan</td><td style="text-align:right; ">182</td><td style="text-align:right; ">185</td><td style="text-align:right; ">158</td><td > </td><td style="background-color:#ccc0da; ">Date</td><td >3-Jan</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >3-Jan</td><td style="text-align:right; ">172</td><td style="text-align:right; ">102</td><td style="background-color:#ffff00; text-align:right; ">199</td><td > </td><td > </td><td > </td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td > Formula</td></tr><tr><td >G1</td><td >=MAX(B2:D4)</td></tr><tr><td >G2</td><td >{=INDEX(B1:D1,0,MAX((B2:D4=G1)*COLUMN(B2:D4)-1))}</td></tr><tr><td >G3</td><td >{=INDEX(A2:A4,MAX((B2:D4=G1)*ROW(A2:A4))-1)}</td></tr></table></td></tr></table>


-----------------------------
If you want for duplicates


<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:40.87px;" /><col style="width:76.04px;" /><col style="width:78.89px;" /><col style="width:77.94px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td><td >G</td><td >H</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Date</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Cashier A</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Cashier B</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Cashier C</td><td > </td><td style="background-color:#ccc0da; ">Max</td><td style="background-color:#ffff00; text-align:right; ">199</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >1-Jan</td><td style="text-align:right; ">164</td><td style="text-align:right; ">156</td><td style="text-align:right; ">157</td><td > </td><td style="background-color:#ccc0da; ">Cashier</td><td >Cashier C</td><td >Cashier B</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >2-Jan</td><td style="text-align:right; ">182</td><td style="background-color:#ffff00; text-align:right; ">199</td><td style="text-align:right; ">158</td><td > </td><td style="background-color:#ccc0da; ">Date</td><td >3-Jan</td><td >2-Jan</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >3-Jan</td><td style="text-align:right; ">172</td><td style="text-align:right; ">102</td><td style="background-color:#ffff00; text-align:right; ">199</td><td > </td><td > </td><td > </td><td > </td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >G1</td><td >=MAX(B2:D4)</td></tr><tr><td >G2</td><td >{=INDEX($B$1:$D$1,0,LARGE(($B$2:$D$4=$G$1)*COLUMN($B$1:$D$1),COLUMNS($G$1:G1))-1)}</td></tr><tr><td >G3</td><td >{=INDEX($A$2:$A$4,LARGE(($B$2:$D$4=$G$1)*ROW($A$2:$A$4),COLUMNS($G$1:G1))-1)}</td></tr></table></td></tr></table>

----------------
The formulas in G2 and G3 are array formulas
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

Copy to H2 and H3
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,159
Members
453,021
Latest member
Justyna P

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