Reference from first and last values in a row

lbird2

Board Regular
Joined
Dec 10, 2014
Messages
78
Office Version
  1. 365
Platform
  1. Windows
[TABLE="class: grid, width: 500, align: center"]
<tbody>[TR]
[TD][/TD]
[TD]Start Date
[/TD]
[TD]End Date
[/TD]
[TD="align: center"]Jan-20
[/TD]
[TD="align: center"]Feb-20
[/TD]
[TD="align: center"]Mar-20
[/TD]
[TD="align: center"]Apr-20
[/TD]
[TD="align: center"]May-20
[/TD]
[TD="align: center"]Jun-20
[/TD]
[TD="align: center"]Jul-20
[/TD]
[/TR]
[TR]
[TD]A
[/TD]
[TD][/TD]
[TD][/TD]
[TD="align: center"][/TD]
[TD="align: center"]212
[/TD]
[TD="align: center"]518
[/TD]
[TD="align: center"]623
[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[/TR]
[TR]
[TD]B
[/TD]
[TD][/TD]
[TD][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"]891
[/TD]
[TD="align: center"]218
[/TD]
[TD="align: center"]563
[/TD]
[TD="align: center"]500
[/TD]
[/TR]
[TR]
[TD]C
[/TD]
[TD][/TD]
[TD][/TD]
[TD="align: center"]926
[/TD]
[TD="align: center"]777
[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[/TR]
</tbody>[/TABLE]

For the table above, I would like to return the dates corresponding to the first and last values in the row.
For example, Start Date for category A would Feb-20, End Date Apr-20.
 

Excel Facts

Quick Sum
Select a range of cells. The total appears in bottom right of Excel screen. Right-click total to add Max, Min, Count, Average.
Try this array formulas

<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:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /></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><td >I</td><td >J</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td > </td><td >Start Date</td><td >End Date</td><td style="text-align:right; ">ene-20</td><td style="text-align:right; ">feb-20</td><td style="text-align:right; ">mar-20</td><td style="text-align:right; ">abr-20</td><td style="text-align:right; ">may-20</td><td style="text-align:right; ">jun-20</td><td style="text-align:right; ">jul-20</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >A</td><td style="text-align:right; ">feb-20</td><td style="text-align:right; ">abr-20</td><td > </td><td style="text-align:right; ">212</td><td style="text-align:right; ">518</td><td style="text-align:right; ">623</td><td > </td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >B</td><td style="text-align:right; ">abr-20</td><td style="text-align:right; ">jul-20</td><td > </td><td > </td><td > </td><td style="text-align:right; ">891</td><td style="text-align:right; ">218</td><td style="text-align:right; ">563</td><td style="text-align:right; ">500</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >C</td><td style="text-align:right; ">ene-20</td><td style="text-align:right; ">feb-20</td><td style="text-align:right; ">926</td><td style="text-align:right; ">777</td><td > </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 >Array Formula</td></tr><tr><td >B2</td><td >{=INDEX($A$1:$J$1,0,MIN(IF($D2:$J2>0,COLUMN($D2:$J2))))}</td></tr><tr><td >C2</td><td >{=INDEX($A$1:$J$1,0,MAX(IF($D2:$J2>0,COLUMN($D2:$J2))))}</td></tr></table></td></tr></table>

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.
 
Upvote 0
How about


Book1
ABCDEFGHIJ
1Start DateEnd DateJan-20Feb-20Mar-20Apr-20May-20Jun-20Jul-20
2AFeb-20Apr-20212518623
3BApr-20Jul-20891218563500
4CJan-20Feb-20926777
Lookup
Cell Formulas
RangeFormula
B2=AGGREGATE(15,6,$D$1:$J$1/(D2:J2>0),1)
C2=AGGREGATE(14,6,$D$1:$J$1/(D2:J2>0),1)
 
Upvote 0
I'm glad to help you. Thanks for the feedback.
 
Upvote 0
You're welcome & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,223,703
Messages
6,173,972
Members
452,540
Latest member
haasro02

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