Lookup column name based on max value within a defined time period

Lilium

New Member
Joined
Jun 6, 2023
Messages
9
Office Version
  1. 2019
Platform
  1. Windows
I have a table "Data" which contains different temperatures recorded by sensors and the time at which a sensor registered the temperature.
Sensor names can be found in row 1 as from column C. Times are in column A.
I would like to find the sensor (name) from row 1 that registered the max temperature during a defined period. The period is defined in tha Analysis tab on cell B2 and C2. The sensor name should be mentioned on B5 of the Analysis tab.
The defined period is mentioned in the tab Analysis.
I've been searching with vlookup but I can't seem to find something that works, I just don't see it.
Any input is much appreciated.

I've included the screenshots.
 

Attachments

  • Analysis-tab.jpg
    Analysis-tab.jpg
    69.5 KB · Views: 17
  • Data-tab.jpg
    Data-tab.jpg
    67.1 KB · Views: 13

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
At 09:37, both sensors 003 and 005 has the maximum value of 20.6. Which one to choose?
 
Upvote 0
Here is a fairly old school way of doing it. It requires that there is only ONE value to match in the given range (so the 20.7 in first row is not selected because it is not in the time range requested).
It can probably be done much easier with some Excel 365 functions. I'm not sure what Excel 2019 functions are available.
Mr Excel Questions 73.xlsm
ABCDEFG
1Data
2TimePoint2202-0012202-0022202-0032202-0042202-005
309:35120.419.920.720.120.8
409:36220.419.920.62020.7
509:37320.419.820.619.920.6
609:38420.319.820.519.820.5
709:39520.319.720.419.820.4
8
9
10Period BegPeriod End
1109:3609:38
12
13Sensor Name
14Hotest Temp in Period2202-005
Sheet5
Cell Formulas
RangeFormula
B14B14=INDEX($C$2:$G$2,SUM((MAX(($B$11<=$A$3:$A$7)*($C$11>=$A$3:$A$7)*($C$3:$G$7))=($C$3:$G$7))* ($B$11<=$A$3:$A$7)*($C$11>=$A$3:$A$7)*(COLUMN($C$2:$G$2)-COLUMN($B$2))))
 
Upvote 0
Here is a fairly old school way of doing it. It requires that there is only ONE value to match in the given range (so the 20.7 in first row is not selected because it is not in the time range requested).
It can probably be done much easier with some Excel 365 functions. I'm not sure what Excel 2019 functions are available.
Mr Excel Questions 73.xlsm
ABCDEFG
1Data
2TimePoint2202-0012202-0022202-0032202-0042202-005
309:35120.419.920.720.120.8
409:36220.419.920.62020.7
509:37320.419.820.619.920.6
609:38420.319.820.519.820.5
709:39520.319.720.419.820.4
8
9
10Period BegPeriod End
1109:3609:38
12
13Sensor Name
14Hotest Temp in Period2202-005
Sheet5
Cell Formulas
RangeFormula
B14B14=INDEX($C$2:$G$2,SUM((MAX(($B$11<=$A$3:$A$7)*($C$11>=$A$3:$A$7)*($C$3:$G$7))=($C$3:$G$7))* ($B$11<=$A$3:$A$7)*($C$11>=$A$3:$A$7)*(COLUMN($C$2:$G$2)-COLUMN($B$2))))
Thank you Awoohaw.
I forgot to mention (see flashbond's reponse), I would like to see all sensor names if more than 1 sensor in the given timeframe has the same max value.
 
Upvote 0
You could try this but note that a sensor will get listed more than once if it has the equal top value in the range more than once - see second example below.

Lilium.xlsm
ABCDEFG
1TimePoint2202-0012202-0022202-0032202-0042202-005
29:35120.419.920.720.120.8
39:36220.419.920.62020.7
49:37320.419.820.619.920.6
59:38420.319.820.519.820.5
69:39520.319.720.419.820.6
Data


Check your table name and table headers in the formula below.

Lilium.xlsm
BCD
1BeginEndHottest Sensors
29:369:382202-005
39:379:392202-003,2202-005,2202-005
Analysis
Cell Formulas
RangeFormula
D2:D3D2=TEXTJOIN(",",1,IF((Table1[Time]<=C2)*(Table1[Time]>=B2)*(Table1[[2202-001]:[2202-005]]=MAX(IF(Table1[Time]>=B2,IF(Table1[Time]<=C2,Table1[[2202-001]:[2202-005]])))),Table1[[#Headers],[2202-001]:[2202-005]],""))
 
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,853
Members
452,361
Latest member
d3ad3y3

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