View Single Post
  #3   Report Post  
Posted to microsoft.public.excel.misc
Gary''s Student Gary''s Student is offline
external usenet poster
 
Posts: 11,058
Default Keeping date from changing

This is an example using cell A1. In A1 we have:

=IF(C4=0,NOW(),IF(C40,"",IF(E4="",NOW(),E4)))

The following worksheet event macro waits for A1 to become "visible":

Private Sub Worksheet_Calculate()

Set a1 = Range("A1")
t = a1.Value
nw = "NOW()"

rp = "date(" & Year(Now()) & "," & Month(Now()) & "," & Day(Now()) & ")"
If Len(t) = 0 Then Exit Sub
f = a1.Formula
If InStr(f, nw) = 0 Then Exit Sub
Application.EnableEvents = False
a1.Formula = Replace(f, nw, rp)
Application.EnableEvents = True
End Sub

The macro sees that the formula contains NOW() and changes it into:

=IF(C4=0,DATE(2008,4,26),IF(C40,"",IF(E4="",DATE( 2008,4,26),E4)))

The macro is smart enough to use the correct values in DATE(). The macro is
also smart enough to "fix" the formula only one time.


Because it is worksheet code, it is very easy to install and automatic to use:

1. right-click the tab name near the bottom of the Excel window
2. select View Code - this brings up a VBE window
3. paste the stuff in and close the VBE window

If you have any concerns, first try it on a trial worksheet.

If you save the workbook, the macro will be saved with it.


To remove the macro:

1. bring up the VBE windows as above
2. clear the code out
3. close the VBE window

To learn more about macros in general, see:

http://www.mvps.org/dmcritchie/excel/getstarted.htm

To learn more about Event Macros (worksheet code), see:

http://www.mvps.org/dmcritchie/excel/event.htm

--
Gary''s Student - gsnu200781