Enter Date Automatically

jpenn

Board Regular
Joined
Jul 15, 2004
Messages
79
Greetings -

I have a Date column (A) and a Serial Number column (B). I would like the Date column to be blank, unless a Serial Number is entered in column B. When a Serial Number is entered, I would like the date to be automatically populated. e.g., I put a serial number in B2 and today's date appears in A2.

In the Date column, I tried =IF(ISBLANK(B11),"",TODAY()) which works fine...today. But tomorrow if I enter a new serial number in B3, then all the dates in column A change to tomorrow's date!

I'm certain there must be a way to do this, I just don't know what it is. Any help from you Excel gurus out there would be most appreciated.
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).
The only way I can think to do this would be with VBA code, specifically a worksheet change event.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target.Count <> 1 Or Target.Column <> 2 Then Exit Sub
    Application.EnableEvents = False
    If Target.Value <> "" Then
        Target.Offset(0, -1) = Date
    Else
        Target.Offset(0, -1) = ""
    End If
    Application.EnableEvents = True
End Sub

EDIT: :oops: Got the columns mixed up.
 
Upvote 0
Right click the sheet tab and choose View Code. Paste this into the window on the right:

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target.Count > 1 Then Exit Sub
    If Target.Column <> 2 Then Exit Sub
    If IsEmpty(Target.Offset(, -1)) Then
        Target.Offset(, -1).Value = Date
    End If
End Sub

Press Alt+F11 to return to your worksheet.
 
Upvote 0
Thanks so much, Andrew and Norie!! Both seem to work equally as well - just what I needed!!
 
Upvote 0

Forum statistics

Threads
1,214,924
Messages
6,122,294
Members
449,077
Latest member
Rkmenon

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