TIME STAMP FOR A RANGE

F

FARAZ QURESHI

I found the following code at http://www.mcgimpsey.com/excel/timestamp.html
quite useful.

The only question is that how to make it work if a series is entered if a
collection/range is changed?
e.g.
1. Selecting A2:A15, entering xyz and hitting Ctrl+Enter; OR
2. Copying xyz from some other place and pasting/filling all the range in a
single stroke?:

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
With Target
If .Count > 1 Then Exit Sub
If Not Intersect(Range("A:A"), .Cells) Is Nothing Then
Application.EnableEvents = False
If IsEmpty(.Value) Then
.Offset(0, 1).ClearContents
Else
With .Offset(0, 1)
.NumberFormat = "dd mmm yyyy hh:mm:ss"
.Value = Now
End With
End If
Application.EnableEvents = True
End If
End With
End Sub
 
D

Dave Peterson

Option Explicit
Private Sub Worksheet_Change(ByVal Target As Excel.Range)
Dim myCell As Range
Dim myRng As Range

With Target
Set myRng = Intersect(.Cells, Me.Range("a2:a15"))
If myRng Is Nothing Then
Exit Sub
End If

For Each myCell In myRng.Cells
Application.EnableEvents = False
If IsEmpty(.Value) Then
.Offset(0, 1).ClearContents
Else
With .Offset(0, 1)
.NumberFormat = "dd mmm yyyy hh:mm:ss"
.Value = Now
End With
End If
Application.EnableEvents = True
Next myCell
End With
End Sub
 
D

Dave Peterson

I have a mistake in this code.

Use this instead:

Option Explicit
Private Sub Worksheet_Change(ByVal Target As Excel.Range)
Dim myCell As Range
Dim myRng As Range

Set myRng = Intersect(Target, Me.Range("a2:a15"))

If myRng Is Nothing Then
Exit Sub
End If

For Each myCell In myRng.Cells
With myCell
Application.EnableEvents = False
If IsEmpty(.Value) Then
.Offset(0, 1).ClearContents
Else
With .Offset(0, 1)
.NumberFormat = "dd mmm yyyy hh:mm:ss"
.Value = Now
End With
End If
Application.EnableEvents = True
End With
Next myCell
End Sub
 

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