Testing dates of unknown format

Deutz

Board Regular
Joined
Nov 30, 2009
Messages
196
Office Version
  1. 365
Platform
  1. Windows
I am using Excel 2003.
<?xml:namespace prefix = o ns = "urn:schemas-microsoft-com:office:office" /><o:p> </o:p>
On a worksheet I have a column of dates (eg. 1/8/2007) that may be in Text, Date or General format, I don’t know how they will be imported each time. Using VBA, I want to make sure that each date is either the first day of the month or the last day. The month is not important. The year needs to fall within a user defined range. Any suggestions on how to do this would be appreciated as I can’t be sure what format the dates will be in and if you try to convert them all to Text or to Date format before applying a formula you get some strange results … days and months get switched or the date is converted into a number.
<o:p> </o:p>
Thanks in advance
<?xml:namespace prefix = st1 ns = "urn:schemas:contacts" /><st1:GivenName w:st="on">Michael</st1:GivenName>
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
You could probably do this with a formula.

Something like

<b>Excel 2010</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #BBB"><colgroup><col width="10px" style="background-color: #DAE7F5" /><col /><col /></colgroup><thead><tr style=" background-color: #DAE7F5;text-align: center;color: #161120"><th></th><th>A</th><th>B</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="text-align: right;;">29-03-2011</td><td style=";">Does Not Match Criteria</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">31-03-2011</td><td style=";">Not a Date</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;">30-03-2011</td><td style=";">Does Not Match Criteria</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;;">31-03-2011</td><td style=";">Matches Criteria</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;">01-04-2011</td><td style=";">Matches Criteria</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;">01-02-2011</td><td style=";">Matches Criteria</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #BBB;border-top:none;text-align: center;background-color: #DAE7F5;color: #161120">Sheet1</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #BBB"><thead><tr style=" background-color: #DAE7F5;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">B1</th><td style="text-align:left">=IF(<font color="Blue">ISNUMBER(<font color="Red">A1</font>),IF(<font color="Red">OR(<font color="Green">A1=EOMONTH(<font color="Purple">A1,-1</font>)+1,A1=EOMONTH(<font color="Purple">A1,0</font>)</font>),"Matches Criteria","Does Not Match Criteria"</font>),"Not a Date"</font>)</td></tr></tbody></table></td></tr></table><br />

Note: If you have XL2003, you will have to enable the Analysis Tool Pack add-in.
 
Upvote 0
Hi Sandeep,

Thanks for your reply. I tested your formula with date: 30/09/2007 which was formatted as TEXT and it did not flag it as a valid date. Works fine if the cell is formatted as DATE. Any idea how to structure a formula that will also pick up dates formatted as TEXT?

Thanks

Michael
 
Upvote 0
If you don't need dates formatted as TEXT flagged, then try

=IF(OR(A1+0=EOMONTH(A1+0,-1)+1,A1+0=EOMONTH(A1+0,0)),"Matches Criteria","Does Not Match Criteria")
 
Upvote 0
Thanks Sandeep, that formula works well, now I just need to determine which formula to use on my data.

I don't suppose there is some way to test what format a cell is in?

Regards
Michael
 
Upvote 0
Try

<b>Excel 2010</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #BBB"><colgroup><col width="10px" style="background-color: #DAE7F5" /><col /><col /></colgroup><thead><tr style=" background-color: #DAE7F5;text-align: center;color: #161120"><th></th><th>A</th><th>B</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="text-align: right;;">29-03-2011</td><td style=";">dd-mm-yyyy</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">31-03-2011</td><td style=";">@</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;">30-03-2011</td><td style=";">dd-mm-yyyy</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;;">31-03-2011</td><td style=";">dd-mm-yyyy</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;">01-04-2011</td><td style=";">dd-mm-yyyy</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;">01-02-2011</td><td style=";">dd-mm-yyyy</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: right;;">40575</td><td style=";">General</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #BBB;border-top:none;text-align: center;background-color: #DAE7F5;color: #161120">Sheet1</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #BBB"><thead><tr style=" background-color: #DAE7F5;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">B1</th><td style="text-align:left">=CellFormat</td></tr></tbody></table></td></tr></table><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Workbook Defined Names</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #BBB"><thead><tr style=" background-color: #DAE7F5;color: #161120"><th width="10px">Name</th><th style="text-align:left">Refers To</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">CellFormat</th><td style="text-align:left">=GET.CELL(<font color="Blue">7,INDIRECT(<font color="Red">"rc[-1]",FALSE</font>)</font>)</td></tr></tbody></table></td></tr></table><br />

This will return the cell format of the cell to the immediate left of the one containing the formula. You can change the "rc[-1]" part if you need to get formatting of cells other than the one to the immediate left.
 
Upvote 0
Pardon my ignorance but where do you put the Workbook defined name formula to make this work?
 
Upvote 0
Press the key combination Alt+I+N+D to get the name manager box.

In Excel 2003 you can find this under Insert | Names | Define Name

In Excel 2007 and higher it is under Formulas | Defined Names | Name Manager (on the ribbon)

Create a new name using the formula in the previous post.
 
Upvote 0
Works like a treat!

Thanks for your help Sandeep.


Regards
Michael
 
Upvote 0

Forum statistics

Threads
1,224,521
Messages
6,179,278
Members
452,902
Latest member
Knuddeluff

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