Second highest with a condition

EinarOSies

Board Regular
Joined
Feb 15, 2021
Messages
51
Office Version
  1. 2019
Platform
  1. Windows
I am having this formula "INDEX($B$4:$B$108,MATCH(MAXIFS(N4:N108,N4:N108,">=1",N4:N108,"<=100"),$N$4:$N$108,0))" which gives me only the first indentification value in column "B" which corresponds to the maximum value in column "N" with a condition of the range from 1-to-100. Just as I said I get only the first identification value in column "B" but the maximum value are more than one(1).



Please can I get a similar formula to find the other identification values in column "B" with the maximum value in column "N" with the condition above. For example 1st ID num.,2nd ID num,............nth ID num with the same maximum value in column "N" which correspondence to column "B".



Thanks.
 

Excel Facts

Enter current date or time
Ctrl+: enters current time. Ctrl+; enters current date. Use Ctrl+: Ctrl+; Enter for current date & time.

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
11,409
Try:

Book2
ABNOP
1
2
3ID ValueID Value
4105
5209
631712
7421 
8597 
963 
107-7 
1188
12997
131021
141177
151297
16130
17140
18152
19163
20174
2118123
2219145
23202
24
Sheet7
Cell Formulas
RangeFormula
P4:P10P4=IFERROR(INDEX(B:B,AGGREGATE(15,6,ROW($B$4:$B$108)/($N$4:$N$108=MAXIFS($N$4:$N$108,$N$4:$N$108,">=1",$N$4:$N$108,"<=100")),ROWS(P$4:P4))),"")
 
Solution

EinarOSies

Board Regular
Joined
Feb 15, 2021
Messages
51
Office Version
  1. 2019
Platform
  1. Windows
Please it seems the formula is giving me wrong results
 

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
11,409

ADVERTISEMENT

In what way? Can you show an example of your sheet with the expected results? Can you use the XL2BB tool to show your sheet? That's what I used in post 2. You can click the link in my signature to get instructions how to load it.
 

EinarOSies

Board Regular
Joined
Feb 15, 2021
Messages
51
Office Version
  1. 2019
Platform
  1. Windows
Please this is a link to the file. it will be recommended to view it in a 70%
File
 

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
11,409

ADVERTISEMENT

I'm sorry, I can't download files from the internet. You'll need to find some other way of explaining your problem, or perhaps someone else would be willing to look at your file.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
62,383
Office Version
  1. 365
Platform
  1. Windows
It's not a valid link, the link is pointing to "http://Please this is a link to the file. it will be recommended to view it in a 70%"
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
62,383
Office Version
  1. 365
Platform
  1. Windows
The data in the file is like
KUMASI ASSEMBLY HALL ECG MONITORING SHEET.xlsx
BCDENOPQR
1DATEDAYDAY2Column3Column4Column5Column6Column7
26AM REC.6PM REC.
3
402/01/2021Saturday6.72.79########31/03/20213.91-478.5
503/01/2021Sunday481.29475.42GH₵13.68 5.8719.55
604/01/2021Monday455.87450.01GH₵12.71 5.8618.57
705/01/2021Tuesday431.44425.58GH₵15.65 5.8621.51
806/01/2021Wednesday404.07389.21GH₵0.57 14.8615.44
907/01/2021Thursday373.77368.89GH₵14.67 4.8819.55
1008/01/2021Friday349.34352.5GH₵32.71 -3.1629.55
1109/01/2021Saturday322.95318.06GH₵13.68TRUE4.8918.57
1210/01/2021Sunday299.49293.63GH₵13.695.8619.55
1311/01/2021Monday274.08268.21GH₵10.7402/03/20215.8716.61
1412/01/2021Tuesday251.6246.65GH₵15.85 4.9520.8
1513/01/2021Wednesday225.85217.53GH₵12.49 8.3220.81
1614/01/2021Thursday196.72189.44GH₵13.52 7.2820.8
1715/01/2021Friday168.64162.4GH₵7.56 6.2413.8
1816/01/2021Saturday148.6136.4GH₵8.60 12.220.8
1917/01/2021Sunday115.6109.35GH₵15.59TRUE6.2521.84
2018/01/2021Monday87.5185.43GH₵19.762.0821.84
2119/01/2021Tuesday63.5957.35GH₵11.4425/01/20216.2417.68
2220/01/2021Wednesday39.6734.47GH₵14.56 5.219.76
2321/01/2021Thursday14.715.34######## 9.37-494.8
2422/01/2021Friday500.14498.06GH₵18.72 2.0820.8
2523/01/2021Saturday477.26469.98GH₵11.44 7.2818.72
2624/01/2021Sunday451.26445.02GH₵19.53 6.2425.77
2725/01/2021Monday419.25409.4GH₵22.96 9.8532.81
2826/01/2021Tuesday376.59366.72GH₵22.95TRUE9.8732.82
2927/01/2021Wednesday333.9320.77GH₵21.3413.1334.47
3028/01/2021Thursday286.3274.81GH₵21.3403/03/202111.4932.83
3129/01/2021Friday241.98232.14GH₵22.99 9.8432.83
3230/01/2021Saturday199.31191.14GH₵21.41 8.1729.58
3331/01/2021Sunday161.56151.71GH₵27.09 9.8536.94
3401/02/2021Monday114.77104.76GH₵5.39 10.0115.4
3502/02/2021Tuesday89.3683.4GH₵13.50 5.9619.46
3603/02/2021Wednesday63.9457.1GH₵11.28TRUE6.8418.12
3704/02/2021Thursday38.9831.69GH₵11.287.2918.57
3805/02/2021Friday13.126.28########6.84-479.47
3906/02/2021Saturday485.75479.89GH₵12.715.8618.57
4007/02/2021Sunday461.3252.52########408.8-381.43
4108/02/2021Monday433.95426.13GH₵13.687.8221.5
4209/02/2021Tuesday404.63398.78GH₵14.685.8520.54
4310/02/2021Wednesday378.24373.35GH₵15.634.8920.52
4411/02/2021Thursday352.83346.96GH₵13.925.8719.8
4512/02/2021Friday327.16319.88-GH₵1.937.285.35
4613/02/2021Saturday314.53288.68-GH₵5.0425.8520.8
4714/02/2021Sunday267.88262.68GH₵16.655.221.85
4815/02/2021Monday240.83233.55GH₵9.357.2816.63
4916/02/2021Tuesday216.92207.55GH₵11.439.3720.8
5017/02/2021Wednesday186.75180.51GH₵11.446.2417.68
5118/02/2021Thursday162.83155.55GH₵13.537.2820.81
5219/02/2021Friday134.74126.42GH₵12.468.3220.78
5320/02/2021Saturday105.6495.22GH₵11.4210.4221.84
5421/02/2021Sunday73.3866.1GH₵12.487.2819.76
5522/02/2021Monday46.3439.05GH₵14.117.2921.4
5623/02/2021Tuesday17.659.65########8-463.69
5724/02/2021Wednesday473.34456.58GH₵16.7216.7633.48
5825/02/2021Thursday423.1414.25GH₵25.628.8534.47
5926/02/2021Friday379.78363.39GH₵16.4616.3932.85
6027/02/2021Saturday330.54320.7GH₵34.489.8444.32
6128/02/2021Sunday276.38236.5-GH₵36.3439.883.54
6201/03/2021Monday232.96229.66GH₵17.223.320.52
6302/03/2021Tuesday209.14201.32GH₵14.337.8222.15
6403/03/2021Wednesday179.17172.97GH₵10.416.216.61
6504/03/2021Thursday156.36150.49GH₵19.545.8725.41
6605/03/2021Friday125.08118.24GH₵15.316.8422.15
6706/03/2021Saturday96.0985.94GH₵12.0010.1522.15
6807/03/2021Sunday63.7958.69-GH₵1.105.14
6908/03/2021Monday54.6944.54-GH₵3.7010.156.45
7009/03/2021Tuesday38.0932.23########5.86-479.47
7110/03/2021Wednesday511.7484.33-GH₵27.3427.370.03
7211/03/2021Thursday484.3478.47GH₵13.725.8319.55
7312/03/2021Friday458.92451.81GH₵13.677.1120.78
7413/03/2021Saturday431.03424.79GH₵15.166.2421.4
7514/03/2021Sunday403.39394.99GH₵10.698.419.09
7615/03/2021Monday375.9370.7GH₵16.955.222.15
7716/03/2021Tuesday348.55338.4GH₵4.3510.1514.5
7817/03/2021Wednesday323.9318.7GH₵14.565.219.76
7918/03/2021Thursday298.94292.69GH₵12.476.2518.72
8019/03/2021Friday273.97268.77GH₵14.555.219.76
8120/03/2021Saturday249.01241.73GH₵10.407.2817.68
8221/03/2021Sunday224.05216.77GH₵11.447.2818.72
8322/03/2021Monday198.05189.72GH₵11.438.3319.76
8423/03/2021Tuesday169.96160.6GH₵10.659.3620.01
8524/03/2021Wednesday140.59132.47GH₵24.708.1232.82
8625/03/2021Thursday99.6591.44GH₵83.238.2191.44
87-GH₵58.610-58.61
8826/03/2021Friday58.6148.46GH₵14.1610.1524.31
8927/03/2021Saturday24.15########24.15-519.22
9027/03/2021Saturday519.22509.07GH₵14.1810.1524.33
9128/03/2021Sunday484.74433.37-GH₵61.7251.37-10.35
9229/03/2021Monday443.72435.52GH₵32.838.241.04
9330/03/2021Tuesday394.48366.58-GH₵5.7527.922.15
9431/03/2021Wednesday344.43334.28GH₵1.7210.1511.87
9501/04/2021Thursday322.41312.26GH₵12.0010.1522.15
DATA RECORDS
Cell Formulas
RangeFormula
N4:N95N4=ROUNDDOWN(SUM(M4-L4),2)
Q4:Q95Q4=SUM(D4-E4)
R4:R95R4=SUM(F4-G4)
P4:P8,P10P4=IFERROR(INDEX($B$4:$B$108,AGGREGATE(15,6,ROW($B$4:$B$108)/($Q$4:$Q$108=MAXIFS($Q$4:$Q$108,$Q$4:$Q$108,">=1",$Q$4:$Q$108,"<=60")),ROWS(P$4:P4))),"")
P9P9=IFERROR(INDEX($B$4:$B$108,AGGREGATE(15,6,ROW($B$4:$B$108)/($Q$4:$Q$108=MAXIFS($Q$4:$Q$108,$Q$4:$Q$108,">=1",$Q$4:$Q$108,"<=100")),ROWS(P$4:P9))),"")
P11P11=IFERROR(INDEX($B$4:$B$108,AGGREGATE(15,6,ROW($B$4:$B$108)/($Q$4:$Q$108=MAXIFS($Q$4:$Q$108,$Q$4:$Q$108,">=1",$Q$4:$Q$108,"<=60")),ROWS(P$4:P5))),"")=""
P13:P18P13=IFERROR(INDEX($B$4:$B$108,AGGREGATE(15,6,ROW($B$4:$B$108)/($R$4:$R$108=MAXIFS($R$4:$R$108,$R$4:$R$108,">=1",$R$4:$R$108,"<=60")),ROWS(P$13:P13))),"")
P19P19=IFERROR(INDEX($B$4:$B$108,AGGREGATE(15,6,ROW($B$4:$B$108)/($R$4:$R$108=MAXIFS($R$4:$R$108,$R$4:$R$108,">=1",$R$4:$R$108,"<=60")),ROWS(P$13:P19))),"")=""
P21:P25,P27P21=IFERROR(INDEX($B$4:$B$108,AGGREGATE(15,6,ROW($B$4:$B$108)/($Q$4:$Q$108=MINIFS($Q$4:$Q$108,$Q$4:$Q$108,">=1",$Q$4:$Q$108,"<=60")),ROWS(P$21:P21))),"")
P26P26=IFERROR(INDEX($B$4:$B$108,AGGREGATE(15,6,ROW($B$4:$B$108)/($Q$4:$Q$108=MINIFS($Q$4:$Q$108,$Q$4:$Q$108,">=1",$Q$4:$Q$108,"<=100")),ROWS(P$21:P26))),"")
P28P28=IFERROR(INDEX($B$4:$B$108,AGGREGATE(15,6,ROW($B$4:$B$108)/($Q$4:$Q$108=MINIFS($Q$4:$Q$108,$Q$4:$Q$108,">=1",$Q$4:$Q$108,"<=60")),ROWS(P$21:P22))),"")=""
P30:P35P30=IFERROR(INDEX($B$4:$B$108,AGGREGATE(15,6,ROW($B$4:$B$108)/($R$4:$R$108=MINIFS($R$4:$R$108,$R$4:$R$108,">=1",$R$4:$R$108,"<=60")),ROWS(P$30:P30))),"")
P36P36=IFERROR(INDEX($B$4:$B$108,AGGREGATE(15,6,ROW($B$4:$B$108)/($R$4:$R$108=MINIFS($R$4:$R$108,$R$4:$R$108,">=1",$R$4:$R$108,"<=60")),ROWS(P$30:P31))),"")=""
D62D62=E61-3.54
D64,D94,D77,D67:D68D64=E63-22.15
E67,E69,E94:E95,E90,E88,E77E67=[@DAY2]-10.15
E68E68=[@DAY2]-5.1
Cells with Conditional Formatting
CellConditionCell FormatStop If True
B33:J33Expression="GH₵ "&TEXT(AGGREGATE(14,6,MID($J$4:$J$108,5,20)/((MID($J$4:$J$108,5,20)+0>=1)*(MID($J$4:$J$108,5,20)+0<=60)),1),"###.00")=B33textNO
B33:J33Expression="GH₵ "&TEXT(AGGREGATE(14,6,MID($J$4:$J$108,5,20)/((MID($J$4:$J$108,5,20)+0>=1)*(MID($J$4:$J$108,5,20)+0<=60)),1),"###.00")=B33textNO
 

Forum statistics

Threads
1,141,309
Messages
5,705,675
Members
421,404
Latest member
Mikecollo

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
Top