Find the position of a date.

eduzs

Well-known Member
Joined
Jul 6, 2014
Messages
704
Office Version
  1. 2019
  2. 2010
Platform
  1. Windows
In column "A" I have texts, values, and one cell with a DATE.
I need to find in which row is there this date.
Is there a formula to do that?
Many thanks
 

Excel Facts

How can you turn a range sideways?
Copy the range. Select a blank cell. Right-click, Paste Special, then choose Transpose.
Could you show some examples along with expected results?
To follow up on Marcelo's question... show us actual values that could be in the cells (do not simplify things by using 1, 2, 3, etc. for you numbers unless those are your real numbers).
 
Upvote 0
Thanks, I have this kind of data in the column "A"

[TABLE="class: grid, width: 83"]
<tbody>[TR]
[TD="width: 83, align: right"]1,43[/TD]
[/TR]
[TR]
[TD="align: right"]50,14
[/TD]
[/TR]
[TR]
[TD]Vendido
[/TD]
[/TR]
[TR]
[TD]Suportes
[/TD]
[/TR]
[TR]
[TD]Resistências[/TD]
[/TR]
[TR]
[TD]Último Preço[/TD]
[/TR]
[TR]
[TD]Papel
[/TD]
[/TR]
[TR]
[TD="align: right"]13/09/2017
[/TD]
[/TR]
[TR]
[TD]MACD[/TD]
[/TR]
</tbody>[/TABLE]

So I need to retrieve this date "13/09/2017", or get the address where it is.

The date is not always the same, nor always in the same cell address in the 1500 rows sheet.

Thanks.
 
Last edited:
Upvote 0
Thanks, I have this kind of data in the column "A"

[TABLE="class: grid, width: 83"]
<tbody>[TR]
[TD="width: 83, align: right"]1,43[/TD]
[/TR]
[TR]
[TD="align: right"]50,14
[/TD]
[/TR]
[TR]
[TD]Vendido
[/TD]
[/TR]
[TR]
[TD]Suportes
[/TD]
[/TR]
[TR]
[TD]Resistências[/TD]
[/TR]
[TR]
[TD]Último Preço[/TD]
[/TR]
[TR]
[TD]Papel
[/TD]
[/TR]
[TR]
[TD="align: right"]13/09/2017
[/TD]
[/TR]
[TR]
[TD]MACD[/TD]
[/TR]
</tbody>[/TABLE]

So I need to retrieve this date "13/09/2017", or get the address where it is.

The date is not always the same, nor always in the same cell address in the 1500 rows sheet.
Give this formula a try (you will probably have to format the cell you put it in as a Date)...

=LOOKUP(9E+99,A:A)
 
Upvote 0
Or maybe this UDF (user Defined Function)
Code:
Function FindDate(r As Range)
    Dim rFound As Range
   
    Application.FindFormat.NumberFormat = "m/d/yyyy"
    Set rFound = r.Find(What:="*", SearchFormat:=True)
    If Not rFound Is Nothing Then
        FindDate = rFound.Row
    Else
        FindDate = "Not Found"
    End If
End Function


[Table="class: grid"][tr][td="bgcolor: #DCE6F1"][/td][td="bgcolor: #DCE6F1"]
A
[/td][td="bgcolor: #DCE6F1"]
B
[/td][td="bgcolor: #DCE6F1"]
C
[/td][/tr]
[tr][td="bgcolor: #DCE6F1"]
1
[/td][td][/td][td][/td][td]
DateRow​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
2
[/td][td]
1,43​
[/td][td][/td][td]
14​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
3
[/td][td]
3,45​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
4
[/td][td]
50,14​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
5
[/td][td]
Vendido​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
6
[/td][td]
MACD​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
7
[/td][td]
Resistências​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
8
[/td][td]
Suportes​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
9
[/td][td]
Resistências​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
10
[/td][td]
Último Preço​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
11
[/td][td]
Último Preço​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
12
[/td][td]
Papel​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
13
[/td][td]
Nível IFR 14​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
14
[/td][td]
13/09/2017​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
15
[/td][td]
MACD​
[/td][td][/td][td][/td][/tr]
[/table]


Formula in C2
=FindDate(A2:A15)

M.
 
Upvote 0
Give this formula a try (you will probably have to format the cell you put it in as a Date)...

=LOOKUP(9E+99,A:A)
Silly me :oops:... a much simpler formula is available (you will still have to format the cell you put it in as a Date).

=MAX(A1:A15)
 
Last edited:
Upvote 0
Or maybe this UDF (user Defined Function)
Code:
Function FindDate(r As Range)
    Dim rFound As Range
   
    Application.FindFormat.NumberFormat = "m/d/yyyy"
    Set rFound = r.Find(What:="*", SearchFormat:=True)
    If Not rFound Is Nothing Then
        FindDate = rFound.Row
    Else
        FindDate = "Not Found"
    End If
End Function
Another way to write a UDF to return the row number...
Code:
Function FindDate(R As Range) As Long
  FindDate = Application.Match(Application.Max(R), R, 0)
End Function
 
Last edited:
Upvote 0
Silly me :oops:... a much simpler formula is available (you will still have to format the cell you put it in as a Date).

=MAX(A1:A15)


Rick,
The stock market in Brazil is up. The IBOVESPA (general index as the Dow Jones in US) today stands at more than 70,000 points.
So your formula is a bit risky ...

Just kidding. :)
Of course you could not know that the data refer to stock quotes in Brazil - the text is in Portuguese.

M.
 
Upvote 0
Thanks Marcelo and Rick,
I understood that there is no way to directly verify the existence of a date, I will use one of the suggested solutions.
 
Upvote 0

Forum statistics

Threads
1,224,040
Messages
6,176,023
Members
452,697
Latest member
CuriousSpreadsheet

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