Conditional Formatting matching Top 3 values in 2 columns

gtd526

Well-known Member
Joined
Jul 30, 2013
Messages
657
Office Version
  1. 2019
Platform
  1. Windows
Hello,
Using Conditional Formatting, how to highlight any matching Top 3 values in 2 different columns.
Columns L & N. Im highlighting Top 3 for both columns, but I only to highlight any matching Top 3 in the same row, if any exists.
In this example only 2 would be highlighted.
Thank you.


Cell Formulas
RangeFormula
L4:L7L4=IFERROR(VLOOKUP(A4,TeamRankings!$AL$2:$AO$33,4,0),"")
M4:M33M4=IFERROR(VLOOKUP($A4,TeamRankings!$AL$3:$AQ$33,6,0),"")
N4:N33N4=IFERROR(IF(MOD(ROW(),2)=0,ROUND(VLOOKUP($A4,TeamRankings!$BI$36:$BL$65,4,0),2),ROUND(VLOOKUP($A4,TeamRankings!$BI$3:$BL$32,4,0),2)),"")
L8L8=IFERROR(VLOOKUP(A8,TeamRankings!AL2:AO33,4,0),"")
L9L9=IFERROR(VLOOKUP(A9,TeamRankings!AL2:AO33,4,0),"")
L10L10=IFERROR(VLOOKUP(A10,TeamRankings!AL2:AO33,4,0),"")
L11L11=IFERROR(VLOOKUP(A11,TeamRankings!AL2:AO33,4,0),"")
L12L12=IFERROR(VLOOKUP(A12,TeamRankings!AL2:AO33,4,0),"")
L13L13=IFERROR(VLOOKUP(A13,TeamRankings!AL2:AO33,4,0),"")
L14L14=IFERROR(VLOOKUP(A14,TeamRankings!AL2:AO33,4,0),"")
L15L15=IFERROR(VLOOKUP(A15,TeamRankings!AL2:AO33,4,0),"")
L16L16=IFERROR(VLOOKUP(A16,TeamRankings!AL2:AO33,4,0),"")
L17L17=IFERROR(VLOOKUP(A17,TeamRankings!AL2:AO33,4,0),"")
L18L18=IFERROR(VLOOKUP(A18,TeamRankings!AL2:AO33,4,0),"")
L19L19=IFERROR(VLOOKUP(A19,TeamRankings!AL2:AO33,4,0),"")
L20L20=IFERROR(VLOOKUP(A20,TeamRankings!AL2:AO33,4,0),"")
L21L21=IFERROR(VLOOKUP(A21,TeamRankings!AL2:AO33,4,0),"")
L22L22=IFERROR(VLOOKUP(A22,TeamRankings!AL2:AO33,4,0),"")
L23L23=IFERROR(VLOOKUP(A23,TeamRankings!AL2:AO33,4,0),"")
L24L24=IFERROR(VLOOKUP(A24,TeamRankings!AL2:AO33,4,0),"")
L25L25=IFERROR(VLOOKUP(A25,TeamRankings!AL2:AO33,4,0),"")
L26L26=IFERROR(VLOOKUP(A26,TeamRankings!AL2:AO33,4,0),"")
L27L27=IFERROR(VLOOKUP(A27,TeamRankings!AL2:AO33,4,0),"")
L28,L32,L30L28=IFERROR(VLOOKUP(A28,TeamRankings!AL2:AO33,4,0),"")
L29,L33,L31L29=IFERROR(VLOOKUP($A29,TeamRankings!$AL$2:$AO$33,4,0),"")
Cells with Conditional Formatting
CellConditionCell FormatStop If True
L4:L33Cell Valuetop 3 valuestextNO
N4:N33Cell Valuetop 3 valuestextNO
N6,N8,N10,N12,N14,N16,N18,N20,N22,N24,N26,N28,N30,N32Expression=AND($B6<0,$N6>0.55,$O6>0,$O6>$O7,$P6>$P7,$R6>$R7,$A6=$AH6,$AI6=TRUE,$AN6<=$AN$1)textNO
N6,N8,N10,N12,N14,N16,N18,N20,N22,N24,N26,N28,N30,N32Expression=AND($B6<0,$N6>0.55,$J6<$J7,$O6>0,$O6>$O7,$P6>$P7,$R6>$R7,$T6>$T7,$V6>$V7,$W6>$W7,$X6>$X7,$Y6>$Y7,$Z6>$Z7,$AI6=TRUE,$AN6<$AN$1)textNO
N6,N8,N10,N12,N14,N16,N18,N20,N22,N24,N26,N28,N30,N32Expression=AND($B6<0,$N6>0.55,$J6<$J7,$O6>0,$O6>$O7,$P6>$P7,$R6>$R7,$T6>$T7,$X6>$X7,$Z6>$Z7,$AI6=TRUE,$AN6<$AN$1)textNO
N6,N8,N10,N12,N14,N16,N18,N20,N22,N24,N26,N28,N30,N32Expression=AND($B6<0,$N6>0.55,$J6<$J7,$O6>0,$O6>$O7,$P6>$P7,$R6>$R7,$X6>$X7,$A6=$AH6,$AI6=TRUE,$AN6<=$AN$1)textNO
N6,N8,N10,N12,N14,N16,N18,N20,N22,N24,N26,N28,N30,N32Expression=AND($B6<0,$N6>0.55,$J6<$J7,$K6>$K7,$O6>0,$O6>$O7,$P6>$P7,$R6>$R7,$A6=$AH6,$AI6=TRUE,$AN6<=$AN$1)textNO
N7,N9,N11,N13,N15,N17,N19,N21,N23,N25,N27,N29,N31,N33Expression=AND($B7<0,$N7>0.55,$O7>0,$O6<$O7,$P6<$P7,$R6<$R7,$A7=$AH7,$AI7=TRUE,$AN7<=$AN$1)textNO
N7,N9,N11,N13,N15,N17,N19,N21,N23,N25,N27,N29,N31,N33Expression=AND($B7<0,$N7>0.55,$J6>$J7,$O7>0,$O6<$O7,$P6<$P7,$R6<$R7,$T6<$T7,$V6<$V7,$W6<$W7,$X6<$X7,$Y6<$Y7,$Z6<$Z7,$AI7=TRUE,$AN7<$AN$1)textNO
N7,N9,N11,N13,N15,N17,N19,N21,N23,N25,N27,N29,N31,N33Expression=AND($B7<0,$N7>0.55,$J6>$J7,$O7>0,$O6<$O7,$P6<$P7,$R6<$R7,$T6<$T7,$X6<$X7,$Z6<$Z7,$AI7=TRUE,$AN7<$AN$1)textNO
N7,N9,N11,N13,N15,N17,N19,N21,N23,N25,N27,N29,N31,N33Expression=AND($B7<0,$N7>0.55,$J6>$J7,$O7>0,$O6<$O7,$P6<$P7,$R6<$R7,$X6<$X7,$A7=$AH7,$AI7=TRUE,$AN7<=$AN$1)textNO
N7,N9,N11,N13,N15,N17,N19,N21,N23,N25,N27,N29,N31,N33Expression=AND($B7<0,$N7>0.55,$J6>$J7,$K6<$K7,$O7>0,$O6<$O7,$P6<$P7,$R6<$R7,$A7=$AH7,$AI7=TRUE,$AN7<=$AN$1)textNO
J4:AF33Cellcontains a blank value textNO
N4:P4,R4,AH4,AI4Expression=AND($B4<0,$N4>0.55,$O4>0,$O4>$O5,$P4>$P5,$R4>$R5,$A4=$AH4,$AI4=TRUE,$AN4<=$AN$1)textNO
J4,N4:P4,R4,T4,V4:Z4,AH4,AI4Expression=AND($B4<0,$N4>0.55,$J4<$J5,$O4>0,$O4>$O5,$P4>$P5,$R4>$R5,$T4>$T5,$V4>$V5,$W4>$W5,$X4>$X5,$Y4>$Y5,$Z4>$Z5,$AI4=TRUE,$AN4<$AN$1)textNO
J4,N4:P4,R4,T4,X4,Z4,AH4,AI4Expression=AND($B4<0,$N4>0.55,$J4<$J5,$O4>0,$O4>$O5,$P4>$P5,$R4>$R5,$T4>$T5,$X4>$X5,$Z4>$Z5,$AI4=TRUE,$AN4<$AN$1)textNO
J4,N4:P4,R4,X4,AH4,AI4Expression=AND($B4<0,$N4>0.55,$J4<$J5,$O4>0,$O4>$O5,$P4>$P5,$R4>$R5,$X4>$X5,$A4=$AH4,$AI4=TRUE,$AN4<=$AN$1)textNO
J4:K4,N4:P4,R4,AH4,AI4Expression=AND($B4<0,$N4>0.55,$J4<$J5,$K4>$K5,$O4>0,$O4>$O5,$P4>$P5,$R4>$R5,$A4=$AH4,$AI4=TRUE,$AN4<=$AN$1)textNO
J5,N5:P5,R5,T5,V5:Z5,AH5,AI5Expression=AND($B5<0,$N5>0.55,$J4>$J5,$O5>0,$O4<$O5,$P4<$P5,$R4<$R5,$T4<$T5,$V4<$V5,$W4<$W5,$X4<$X5,$Y4<$Y5,$Z4<$Z5,$AI5=TRUE,$AN5<$AN$1)textNO
J5,N5:P5,R5,T5,X5,Z5,AH5,AI5Expression=AND($B5<0,$N5>0.55,$J4>$J5,$O5>0,$O4<$O5,$P4<$P5,$R4<$R5,$T4<$T5,$X4<$X5,$Z4<$Z5,$AI5=TRUE,$AN5<$AN$1)textNO
J5,N5:P5,R5,X5,AH5,AI5Expression=AND($B5<0,$N5>0.55,$J4>$J5,$O5>0,$O4<$O5,$P4<$P5,$R4<$R5,$X4<$X5,$A5=$AH5,$AI5=TRUE,$AN5<=$AN$1)textNO
J5:K5,N5:P5,R5,AH5,AI5Expression=AND($B5<0,$N5>0.55,$J4>$J5,$K4<$K5,$O5>0,$O4<$O5,$P4<$P5,$R4<$R5,$A5=$AH5,$AI5=TRUE,$AN5<=$AN$1)textNO
N5:P5,R5,AH5,AI5Expression=AND($B5<0,$N5>0.55,$O5>0,$O4<$O5,$P4<$P5,$R4<$R5,$A5=$AH5,$AI5=TRUE,$AN5<=$AN$1)textNO
L2,L3:O3Expression=$AY$3="020"textNO
J4:AB33Expression=AND(ISODD(ROW(J4)),J4=J3)textNO
J4:AB33Expression=AND(ISEVEN(ROW(J4)),J4=J5)textNO
K4:P33,R4:R33,T4:AB33Expression=K4=MAX(OFFSET(K$4,FLOOR(ROW(K4)-ROW(K$4),2),0,2,1))textNO
M4:M33Cell Value<=0textNO
M4:M33Cell Value>0textNO
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Try this:

varios 10ene2023.xlsm
LMN
2ATSCover2 %
3Cover%ATS +/-
460.0%3.556%
541.0%-232%
647.5%-0.150%
757.9%0.967%
846.2%-1.460%
947.5%-1.850%
1052.6%1.735%
1153.5%153%
1248.8%-1.445%
1346.2%-3.170%
1452.5%1.744%
1556.4%1.467%
1635.9%-2.332%
1747.6%-245%
Hoja12
Cells with Conditional Formatting
CellConditionCell FormatStop If True
L4:L17,N4:N17Expression=AND(OR($L4=LARGE($L$4:$L$17,1),$L4=LARGE($L$4:$L$17,2),$L4=LARGE($L$4:$L$17,3)),OR($N4=LARGE($N$4:$N$17,1),$N4=LARGE($N$4:$N$17,2),$N4=LARGE($N$4:$N$17,3)))textNO
 
Upvote 0
Solution
Select L$:L17 and N4:N17 ((use Ctrl). Formula for CF.
Excel Formula:
=AND($L4>=LARGE($L$4:$L$17,3),$N4>=LARGE($N$4:$N$17,3))
 
Upvote 0
Try this:

varios 10ene2023.xlsm
LMN
2ATSCover2 %
3Cover%ATS +/-
460.0%3.556%
541.0%-232%
647.5%-0.150%
757.9%0.967%
846.2%-1.460%
947.5%-1.850%
1052.6%1.735%
1153.5%153%
1248.8%-1.445%
1346.2%-3.170%
1452.5%1.744%
1556.4%1.467%
1635.9%-2.332%
1747.6%-245%
Hoja12
Cells with Conditional Formatting
CellConditionCell FormatStop If True
L4:L17,N4:N17Expression=AND(OR($L4=LARGE($L$4:$L$17,1),$L4=LARGE($L$4:$L$17,2),$L4=LARGE($L$4:$L$17,3)),OR($N4=LARGE($N$4:$N$17,1),$N4=LARGE($N$4:$N$17,2),$N4=LARGE($N$4:$N$17,3)))textNO
Thank you.
 
Upvote 0
In future please mark the post that contains the solution as the solution, not your post saying it worked. Thanks
 
Upvote 0

Forum statistics

Threads
1,215,071
Messages
6,122,963
Members
449,094
Latest member
Anshu121

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