dates in macros

M

Max Scott

Hi

I have a problem with a filter in a macro. I recorded a macro and it gave
following code:

selection.autofilter field:=1, Criteria1:="13/12/07"

(This is date type dd/mm/yy by the way)

But when I change the criteria1 to "14/12/07" and run the macro it does not
filter correctly.

Is there something special I need to do with dates?

Thanks

Max
 
R

R

Hi,

Try this kind of construction

Sub AutofilterDate()
Dim MyDate, FindDate As Date
MyDate = "13/12/2007"
FindDate = Year(MyDate) & "/" & Month(MyDate) & "/" & Day(MyDate)
Selection.AutoFilter field:=1, Criteria1:=FindDate
End Sub

Reijo
 
D

Dave Peterson

Just to add to Ron's response...

Ron sent me this message in a private email a few months ago:

See also Stephen his Autofilter notes in this PDF
http://www.oaltd.co.uk/ExcelProgRef/Ch22/ProgRefCh22.htm

The AutoFilter method of a Range object is a very curious beast. We are forced
to pass it strings for its filter criteria and hence must be aware of its string
handling behaviour. The criteria string consists of an operator (=, >, <, >=
etc.) followed by a value. If no operator is specified, the "=" operator is
assumed. The key issue is that when using the "=" operator, AutoFilter performs
a textual match, while using any other operator results in a match by value.
This gives us problems when trying to locate exact matches for dates and
numbers. If we use "=", Excel matches on the text that is displayed in the cell,
i.e. the formatted number. As the text displayed in a cell will change with
different regional settings and Windows language version, it is impossible for
us to create a criteria string that will locate an exact match in all locales.

There is a workaround for this problem. When using any of the other filter
criteria, Excel plays by the rules and interprets the criteria string according
to US formats. Hence, a search criterion of ">=02/01/2001" will find all dates
on or after 1st Feb, 2001, in all locales. We can use this to match an exact
date by using two AutoFilter criteria. The following code will give an exact
match on 1st Feb, 2001 and will work in any locale:


Range("A1:D200").AutoFilter 2, ">=02/01/2001", xlAnd, "<=02/01/2001"
 
R

Ron de Bruin

Hi Dave

Good morning

Thanks for posting the notes I send you (will remember to do it also the next time)

I send a bug report yesterday about it.

If you record a macro when you do it manual the macro recorder record the system
Date format and that is not working when you have another Date format as US on your system.
You must change it in the US date format MM/DD/YYYY then

Confusing
 
R

Ron de Bruin

You should move to the USA and just live with one date format <vvbg>.

Do you have a room for me Dave <g>
 
R

Ron de Bruin

Move to Canada. We'll take anybody<g>

LOL

When I was 8 years old I visit Canada with my parents.
It is a beautiful country Gord.
 
D

Dave Peterson

And they're very polite!

Do you know how to get 20 Canadian's out of a pool?

You ask them.
 

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

Similar Threads

Problem with date formatting 5
Autofilter in a macro 1
Custom filter 26
Filtering and user input 4
Help me4 2
macro filter column for most recent date 3
Autofilter / Sort in VBA doesn't work 2
Filter Problem 2

Top