Find 2nd Largest, 3rd Largest Value

gtd526

Well-known Member
Joined
Jul 30, 2013
Messages
657
Office Version
  1. 2019
Platform
  1. Windows
Hello,
Im using the following array to find the MAX value of a Named Range (NBAGL as array), which is working.
How can I find the 2nd Largest, 3rd Largest value using this array?
{=INDIRECT(INDEX(NBAGL,MATCH(MAX(N(INDIRECT(NBAGL))),N(INDIRECT(NBAGL)),0)))}
thank you.
 
I had suspected that might be the case, your original formula is one of those where the full purpose is not immediately obvious without supporting data and all of the necessary information.

It works for me by adding the N() function, although that may not be the same for excel 2019
Excel Formula:
=LARGE(N(INDIRECT(NBAGL)),1)
The formula below also works as a non-volatile alternative, although, noting that you are using INDIRECT with the same range in several formulas, only making one non-volatile would not really serve any purpose.
Excel Formula:
=AGGREGATE(14,6,AM12:BE66/(MOD(ROW(AM12:BE66)-ROW(AM12),9)=0)/(MOD(COLUMN(AM12:BE66)-COLUMN(AM12),5)=0),1)
The second formula you supplied is working (aggregate)!! I changed the ,1 to ,2 ,3 ,4 and get the 2nd, 3rd and 4th highest value. I will work on the % (AW1, AW2) using the formula you provided. (if possible).
Thank you!
NBA.xlsm
AJAKALAMANAOAPAQARASATAUAVAWAXAYAZBABBBC
1MAX $$Lime = 4,250,140MAX %Pink = 255,110,1702nd $:$47.202nd %:60%$25.95
2NRtg/A (Y:Y)# of Bets:150(S,T,U,V,W) S:W# of Bets:123rd $:$30.153rd %:60%
3026 026- NRtg/A (Y:Y) $90.4058.7%015015- (S,T,U,V,W) S:W75.0%$25.95
4ATS ONLYml ONLY
5001- MOV>ATS (R:R > 0)008- Asst/Tovr Ratio (V:V)015- (S,T,U,V,W) S:W022- Asst/Tovr Ratio (V:V)
6CurrentTotalCurrentTotalCurrentTotalCurrentTotal
7W:0W:360.0%W:0W:7751.3%W:0W:975.0%W:0W:7852.0%
8L:0L:2L:0L:73L:0L:3L:0L:72
9Psh:0Psh:0Psh:0Psh:2Psh:0Psh:0Psh:0Psh:0
10Previous5Previous150Previous12Previous150
11W:3$ 13.65W:77$ 350.35W:9$ 40.95W:78$ 354.90
12L:2$ 10.00$ 3.65L:73$ 365.00$ (14.65)L:3$ 15.00$ 25.95L:72$ 360.00$ (5.10)
13Psh:0Psh:2Psh:0Psh:0
14002- Ct of 9009- Asst/FGM (W:W)016- (S,T,U) S:U023- Asst/FGM (W:W)
15CurrentTotalCurrentTotalCurrentTotalCurrentTotal
16W:0W:1045.5%W:0W:8455.6%W:0W:3357.9%W:0W:8053.0%
17L:0L:12L:0L:67L:0L:24L:0L:71
18Psh:0Psh:0Psh:0Psh:2Psh:0Psh:0Psh:0Psh:0
19Previous22Previous151Previous57Previous151
20W:10$ 45.50W:84$ 382.20W:33$ 150.15W:80$ 364.00
21L:12$ 60.00$ (14.50)L:67$ 335.00$ 47.20L:24$ 120.00$ 30.15L:71$ 355.00$ 9.00
22Psh:0Psh:2Psh:0Psh:0
Favs
Cell Formulas
RangeFormula
AZ1AZ1=AGGREGATE(14,6,AM12:BE66/(MOD(ROW(AM12:BE66)-ROW(AM12),9)=0)/(MOD(COLUMN(AM12:BE66)-COLUMN(AM12),5)=0),4)
AJ2AJ2=TRIM(MID($AK$3,FIND("-",$AK$3)+1,99))
AM2AM2=OFFSET(INDIRECT(INDEX(NBAGL,MATCH(MAX(N(INDIRECT(NBAGL))),N(INDIRECT(NBAGL)),0))),-2,0)
AO2AO2=TRIM(MID($AP$3,FIND("-",$AP$3)+1,99))
AR2AR2=OFFSET(INDIRECT(INDEX(NBAMaxRange,MATCH(MAX(N(INDIRECT(NBAMaxRange))),N(INDIRECT(NBAMaxRange)),0))),3,-1)
AU1AU1=AGGREGATE(14,6,AM12:BE66/(MOD(ROW(AM12:BE66)-ROW(AM12),9)=0)/(MOD(COLUMN(AM12:BE66)-COLUMN(AM12),5)=0),2)
AU2AU2=AGGREGATE(14,6,AM12:BE66/(MOD(ROW(AM12:BE66)-ROW(AM12),9)=0)/(MOD(COLUMN(AM12:BE66)-COLUMN(AM12),5)=0),3)
AW1AW1=LARGE(INDIRECT(NBAMaxRange,2),1)
AW2AW2=LARGE(INDIRECT(NBAMaxRange,3),1)
AJ3,AO3AJ3=IF(LEN(LEFT(AK3,SEARCH("-",AK3)-1))=3,LEFT(AK3,3),LEFT(AK3,1))
AK3AK3=OFFSET(INDIRECT(INDEX(NBAGL,MATCH(MAX(N(INDIRECT(NBAGL))),N(INDIRECT(NBAGL)),0))),-7,-3)
AL3AL3=INDIRECT(INDEX(NBAGL,MATCH(MAX(N(INDIRECT(NBAGL))),N(INDIRECT(NBAGL)),0)))
AM3AM3=OFFSET(INDIRECT(INDEX(NBAGL,MATCH(MAX(N(INDIRECT(NBAGL))),N(INDIRECT(NBAGL)),0))),-5,1)
AP3AP3=OFFSET(INDIRECT(INDEX(NBAMaxRange,MATCH(MAX(N(INDIRECT(NBAMaxRange))),N(INDIRECT(NBAMaxRange)),0))),-2,-4)
AQ3AQ3=INDIRECT(INDEX(NBAMaxRange,MATCH(MAX(N(INDIRECT(NBAMaxRange))),N(INDIRECT(NBAMaxRange)),0)))
AR3AR3=OFFSET(INDIRECT(INDEX(NBAMaxRange,MATCH(MAX(N(INDIRECT(NBAMaxRange))),N(INDIRECT(NBAMaxRange)),0))),5,-1)
AN7,BC16,AX16,AS16,AN16,BC7,AX7,AS7AN7=IFERROR((AM7/AM10),"")
AK7AK7=COUNTIFS($R$4:$R$29,">0",$D$4:$D$29,"W")+(AK9*0.5)
AK8AK8=COUNTIFS($R$4:$R$29,">0",$D$4:$D$29,"L")+(AK9*0.5)
AK9AK9=COUNTIFS($R$4:$R$29,">0",$D$4:$D$29,"Psh")
AP7AP7=SUMPRODUCT(($D$4:$D$29="W")*($V$4:$V$29=SUBTOTAL(4,OFFSET($V$4,ROW($V$4:$V$29)-ROW($V$4),,IF(MOD(ROW($V$4:$V$29),2),-2,2),1))))+(AP9*0.5)
AP8AP8=SUMPRODUCT(($D$4:$D$29="L")*($V$4:$V$29=SUBTOTAL(4,OFFSET($V$4,ROW($V$4:$V$29)-ROW($V$4),,IF(MOD(ROW($V$4:$V$29),2),-2,2),1))))+(AP9*0.5)
AP9AP9=SUMPRODUCT(($D$4:$D$29="Psh")*($V$4:$V$29=SUBTOTAL(4,OFFSET($V$4,ROW($V$4:$V$29)-ROW($V$4),,IF(MOD(ROW($V$4:$V$29),2),-2,2),1))))
AU7AU7=SUMPRODUCT(($D$4:$D$29="W")*($S$4:$S$29=SUBTOTAL(4,OFFSET($S$4,ROW($S$4:$S$29)-ROW($S$4),,IF(MOD(ROW($S$4:$S$29),2),-2,2),1)))*($T$4:$T$29=SUBTOTAL(4,OFFSET($T$4,ROW($T$4:$T$29)-ROW($T$4),,IF(MOD(ROW($T$4:$T$29),2),-2,2),1)))*($U$4:$U$29=SUBTOTAL(4,OFFSET($U$4,ROW($U$4:$U$29)-ROW($U$4),,IF(MOD(ROW($U$4:$U$29),2),-2,2),1)))*($V$4:$V$29=SUBTOTAL(4,OFFSET($V$4,ROW($V$4:$V$29)-ROW($V$4),,IF(MOD(ROW($V$4:$V$29),2),-2,2),1)))*($W$4:$W$29=SUBTOTAL(4,OFFSET($W$4,ROW($W$4:$W$29)-ROW($W$4),,IF(MOD(ROW($W$4:$W$29),2),-2,2),1))))+(AU9*0.5)
AU8AU8=SUMPRODUCT(($D$4:$D$29="L")*($S$4:$S$29=SUBTOTAL(4,OFFSET($S$4,ROW($S$4:$S$29)-ROW($S$4),,IF(MOD(ROW($S$4:$S$29),2),-2,2),1)))*($T$4:$T$29=SUBTOTAL(4,OFFSET($T$4,ROW($T$4:$T$29)-ROW($T$4),,IF(MOD(ROW($T$4:$T$29),2),-2,2),1)))*($U$4:$U$29=SUBTOTAL(4,OFFSET($U$4,ROW($U$4:$U$29)-ROW($U$4),,IF(MOD(ROW($U$4:$U$29),2),-2,2),1)))*($V$4:$V$29=SUBTOTAL(4,OFFSET($V$4,ROW($V$4:$V$29)-ROW($V$4),,IF(MOD(ROW($V$4:$V$29),2),-2,2),1)))*($W$4:$W$29=SUBTOTAL(4,OFFSET($W$4,ROW($W$4:$W$29)-ROW($W$4),,IF(MOD(ROW($W$4:$W$29),2),-2,2),1))))+(AU9*0.5)
AU9AU9=SUMPRODUCT(($D$4:$D$29="psh")*($S$4:$S$29=SUBTOTAL(4,OFFSET($S$4,ROW($S$4:$S$29)-ROW($S$4),,IF(MOD(ROW($S$4:$S$29),2),-2,2),1)))*($T$4:$T$29=SUBTOTAL(4,OFFSET($T$4,ROW($T$4:$T$29)-ROW($T$4),,IF(MOD(ROW($T$4:$T$29),2),-2,2),1)))*($U$4:$U$29=SUBTOTAL(4,OFFSET($U$4,ROW($U$4:$U$29)-ROW($U$4),,IF(MOD(ROW($U$4:$U$29),2),-2,2),1)))*($V$4:$V$29=SUBTOTAL(4,OFFSET($V$4,ROW($V$4:$V$29)-ROW($V$4),,IF(MOD(ROW($V$4:$V$29),2),-2,2),1)))*($W$4:$W$29=SUBTOTAL(4,OFFSET($W$4,ROW($W$4:$W$29)-ROW($W$4),,IF(MOD(ROW($W$4:$W$29),2),-2,2),1))))
AZ7AZ7=SUMPRODUCT(($C$4:$C$29="W")*($V$4:$V$29=SUBTOTAL(4,OFFSET($V$4,ROW($V$4:$V$29)-ROW($V$4),,IF(MOD(ROW($V$4:$V$29),2),-2,2),1))))+(AZ9*0.5)
AZ8AZ8=SUMPRODUCT(($C$4:$C$29="L")*($V$4:$V$29=SUBTOTAL(4,OFFSET($V$4,ROW($V$4:$V$29)-ROW($V$4),,IF(MOD(ROW($V$4:$V$29),2),-2,2),1))))+(AZ9*0.5)
AZ9AZ9=SUMPRODUCT(($C$4:$C$29="Psh")*($V$4:$V$29=SUBTOTAL(4,OFFSET($V$4,ROW($V$4:$V$29)-ROW($V$4),,IF(MOD(ROW($V$4:$V$29),2),-2,2),1))))
BB16:BB17,AW16:AW17,AR16:AR17,AM16:AM17,BB7:BB8,AW7:AW8,AR7:AR8,AM7:AM8AM7=AK11+AK7
AM9,BB18,AW18,AR18,AM18,BB9,AW9,AR9AM9=AK9+AK13
AM10,BB19,AW19,AR19,AM19,BB10,AW10,AR10AM10=AM7+AM8
AL11,BA20,AV20,AQ20,AL20,BA11,AV11,AQ11AL11=AK11*4.55
AL12,BA21,AV21,AQ21,AL21,BA12,AV12,AQ12AL12=AK12*5
AM12,BB21,AW21,AR21,AM21,BB12,AW12,AR12AM12=AL11-AL12
AK16AK16=COUNTIFS(AD4:AD29,"9",D4:D29,"W")+(AK18*0.5)
AK17AK17=COUNTIFS(AD4:AD29,"9",D4:D29,"L")+(AK18*0.5)
AK18AK18=COUNTIFS(AD4:AD29,"9",D4:D29,"Psh")
AP16AP16=SUMPRODUCT(($D$4:$D$29="W")*($W$4:$W$29=SUBTOTAL(4,OFFSET($W$4,ROW($W$4:$W$29)-ROW($W$4),,IF(MOD(ROW($W$4:$W$29),2),-2,2),1))))+(AP18*0.5)
AP17AP17=SUMPRODUCT(($D$4:$D$29="L")*($W$4:$W$29=SUBTOTAL(4,OFFSET($W$4,ROW($W$4:$W$29)-ROW($W$4),,IF(MOD(ROW($W$4:$W$29),2),-2,2),1))))+(AP18*0.5)
AP18AP18=SUMPRODUCT(($D$4:$D$29="psh")*($W$4:$W$29=SUBTOTAL(4,OFFSET($W$4,ROW($W$4:$W$29)-ROW($W$4),,IF(MOD(ROW($W$4:$W$29),2),-2,2),1))))
AU16AU16=SUMPRODUCT(($D$4:$D$29="W")*($S$4:$S$29=SUBTOTAL(4,OFFSET($S$4,ROW($S$4:$S$29)-ROW($S$4),,IF(MOD(ROW($S$4:$S$29),2),-2,2),1)))*($T$4:$T$29=SUBTOTAL(4,OFFSET($T$4,ROW($T$4:$T$29)-ROW($T$4),,IF(MOD(ROW($T$4:$T$29),2),-2,2),1)))*($U$4:$U$29=SUBTOTAL(4,OFFSET($U$4,ROW($U$4:$U$29)-ROW($U$4),,IF(MOD(ROW($U$4:$U$29),2),-2,2),1))))+(AU18*0.5)
AU17AU17=SUMPRODUCT(($D$4:$D$29="L")*($S$4:$S$29=SUBTOTAL(4,OFFSET($S$4,ROW($S$4:$S$29)-ROW($S$4),,IF(MOD(ROW($S$4:$S$29),2),-2,2),1)))*($T$4:$T$29=SUBTOTAL(4,OFFSET($T$4,ROW($T$4:$T$29)-ROW($T$4),,IF(MOD(ROW($T$4:$T$29),2),-2,2),1)))*($U$4:$U$29=SUBTOTAL(4,OFFSET($U$4,ROW($U$4:$U$29)-ROW($U$4),,IF(MOD(ROW($U$4:$U$29),2),-2,2),1))))+(AU18*0.5)
AU18AU18=SUMPRODUCT(($D$4:$D$29="psh")*($S$4:$S$29=SUBTOTAL(4,OFFSET($S$4,ROW($S$4:$S$29)-ROW($S$4),,IF(MOD(ROW($S$4:$S$29),2),-2,2),1)))*($T$4:$T$29=SUBTOTAL(4,OFFSET($T$4,ROW($T$4:$T$29)-ROW($T$4),,IF(MOD(ROW($T$4:$T$29),2),-2,2),1)))*($U$4:$U$29=SUBTOTAL(4,OFFSET($U$4,ROW($U$4:$U$29)-ROW($U$4),,IF(MOD(ROW($U$4:$U$29),2),-2,2),1))))
AZ16AZ16=SUMPRODUCT(($C$4:$C$29="W")*($W$4:$W$29=SUBTOTAL(4,OFFSET($W$4,ROW($W$4:$W$29)-ROW($W$4),,IF(MOD(ROW($W$4:$W$29),2),-2,2),1))))+(AZ18*0.5)
AZ17AZ17=SUMPRODUCT(($C$4:$C$29="L")*($W$4:$W$29=SUBTOTAL(4,OFFSET($W$4,ROW($W$4:$W$29)-ROW($W$4),,IF(MOD(ROW($W$4:$W$29),2),-2,2),1))))+(AZ18*0.5)
AZ18AZ18=SUMPRODUCT(($C$4:$C$29="psh")*($W$4:$W$29=SUBTOTAL(4,OFFSET($W$4,ROW($W$4:$W$29)-ROW($W$4),,IF(MOD(ROW($W$4:$W$29),2),-2,2),1))))
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).

Forum statistics

Threads
1,214,825
Messages
6,121,788
Members
449,049
Latest member
greyangel23

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