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