First, Last occurance of date in column

J

JumboShrimps

Have ONE column of a little more then 1,000 dates, each in a different
cell.
Column is NOT in date order, nor can it be sorted.
Need to to know the first CELL LOCATION of a date,
and then the last CELL LOCATION of a date all in ONE (same) column.
Average 100 cells between first cell location of date and last cell
location.

Thanx.
 
S

Scott

Have ONE column of a little more then 1,000 dates, each in a different
cell.
Column is NOT in date order, nor can it be sorted.
Need to to know the first CELL LOCATION of a date,
and then the last CELL LOCATION of a date all in ONE (same) column.
Average 100 cells between first cell location of date and last cell
location.

Thanx.

I'll use the following, you most likely have them elsewhere.
- Dates in Column A starting in A5.
- Date being looked for in cell A1.

First row:
A2: =MIN(IF(A5:A1004=A1,ROW(A5:A1004),"")) entered with CTRL+SHIFT
+ENTER.

Last row:
A3: =MAX(IF(A5:A1004=A1,ROW(A5:A1004),"")) entered with CTRL+SHIFT
+ENTER.

If you need an actual cell location, you can go:
B2: =ADDRESS(A2,COLUMN(A5))
B3: =ADDRESS(A3,COLUMN(A5))

S
 
R

Ron Rosenfeld

Have ONE column of a little more then 1,000 dates, each in a different
cell.
Column is NOT in date order, nor can it be sorted.
Need to to know the first CELL LOCATION of a date,
and then the last CELL LOCATION of a date all in ONE (same) column.
Average 100 cells between first cell location of date and last cell
location.

Thanx.

If the dates are in column A, and the date to find is in G2, then:

First Occurrence will be in row: =MATCH($G$2,$A:$A,0)
Last Occurrence will be in row: =LOOKUP(2,1/($G$2=$A:$A),ROW($A:$A))

If you need the actual address, use the ADDRESS function to give:

First Address: =ADDRESS(MATCH($G$2,$A:$A,0),1)
Last Address: =ADDRESS(LOOKUP(2,1/($G$2=$A:$A),ROW($A:$A)),1)
 
I

isabelle

hi JumboShrimps,

for the last cell location
that is an array formula to validate with ctrl+maj+enter

=ADDRESS(MAX(IF(A1:A500<>"",ROW(A1:A500))),MAX(IF(A1:A500<>"",COLUMN(A1:A500))))

--
isabelle




Le 2011-11-03 13:12, JumboShrimps a écrit :
 
I

isabelle

for the last row location,

=ROW(INDIRECT(ADDRESS(MAX(IF($A$1:$A$500<>"",ROW($A$1:$A$500))),MAX(IF($A$1:$A$500<>"",COLUMN($A$1:$A$500))))))

still validate with Ctrl + Shift + Enter
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top