WorkSheet Event clear a range if the same range in other column is cleared

RomulusMilea

Board Regular
Joined
May 11, 2002
Messages
175
Hello All,

Below code works just fine. Section 1 adds in column A a timestamp, if something is written in column C (same row).

Section 2 does the opposite, i.e. if value in column C (in one cell, only) is deleted, then the value on the same row (one cell, only), but in column A is simple deleted, too. So far, so good :biggrin:.

The issue is that Section 2 works for one cell at the time, it does not work if I select 2 or more cells. What I need is an improvement of Section 2, I mean if I select any number of cells in column C (more than one cell) and I clear the values in selected cells, then the corresponding range in column A (same rows as selection in column C) to be cleared, as well.

Of course, the way improved section 2 should work must not change/cancel/interfere the job done by section 1.

Any idea, please ?

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

On Error GoTo Handler

' Start of Section 1
If Target.Column = 3 And Target.Value <> "" Then
    Application.EnableEvents = False
    Target.Offset(0, -2) = Format(Now(), "d-mmm-yyyy h:mm")
    Application.EnableEvents = True
End If
'End of Section 1

'Start of Section 2
If Target.Column = 3 And Target.Value = "" Then
    Application.EnableEvents = False
    Target.Offset(0, -2).ClearContents
    Application.EnableEvents = True
End If
'End of Section 2

Handler:
End Sub
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
This will affect section 1 but only if you enter into multiple cells at once with either a Ctrl+Enter or a copy paste.

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim cell As Range
        
    On Error GoTo Handler
    
    ' Start of Section 1
    For Each cell In Target
        If cell.Column = 3 And cell.Value <> "" Then
            Application.EnableEvents = False
            Target.Offset(0, -2) = Format(Now(), "d-mmm-yyyy h:mm")
            Application.EnableEvents = True
        End If
    Next cell
    'End of Section 1
    
    'Start of Section 2
    For Each cell In Target
        If cell.Column = 3 And cell.Value = "" Then
            Application.EnableEvents = False
            Target.Offset(0, -2).ClearContents
            Application.EnableEvents = True
        End If
    Next cell
    'End of Section 2

Handler:
End Sub
 
Upvote 0
This will affect section 1 but only if you enter into multiple cells at once with either a Ctrl+Enter or a copy paste.

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim cell As Range
       
    On Error GoTo Handler
   
    ' Start of Section 1
    For Each cell In Target
        If cell.Column = 3 And cell.Value <> "" Then
            Application.EnableEvents = False
            Target.Offset(0, -2) = Format(Now(), "d-mmm-yyyy h:mm")
            Application.EnableEvents = True
        End If
    Next cell
    'End of Section 1
   
    'Start of Section 2
    For Each cell In Target
        If cell.Column = 3 And cell.Value = "" Then
            Application.EnableEvents = False
            Target.Offset(0, -2).ClearContents
            Application.EnableEvents = True
        End If
    Next cell
    'End of Section 2

Handler:
End Sub
Hello Alex,

It works very well. I have tried several potential solutions, except this one with For ... Next. Thank you very much ! I really appreciate your help, well done !
 
Upvote 0

Forum statistics

Threads
1,213,494
Messages
6,113,972
Members
448,537
Latest member
Et_Cetera

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