How to record data entered by a formula when the referenced cell changes

dubdan

New Member
Joined
Apr 14, 2022
Messages
7
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Hi,

i am working on a Shared workbook that will track time taken to complete tasks.

i have a Status Column - M, i then have a Started at Column - N and a Finished at column - O.

The started/finished at column has a formula that enters a time stamp based on the following statuses - Ongoing/Completed.

=IF(M4="Ongoing",IF(N4="",NOW(),N4),"")

My issue is that once the status has changed from Ongoing to Completed the start time disappears. is there a way (im assuming it will use VBA) to save the data entered into the columns so i can record the time taken to complete the task. id then like to protect the cells from being edited by the operator.

Any help would be much appreciated.
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Worksheet_Change event procedures get really unhappy if you delete rows of data, unless you specifically account for that.
We can add a line of code at the top of our screen to ignore when massive amount of cells are updated at once (like with a deletion), like this:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

    Dim rng As Range, cell As Range
   
'   Exit if more than 100 cells updated at once (row deletion)
    If Target.CountLarge > 100 Then Exit Sub
   
'   Set range to watch
    Set rng = Intersect(Columns("M:M"), Target)
   
'   Exit if no cells in watched range updated
    If rng Is Nothing Then Exit Sub
   
'   Loop through updated cells in watched range
    For Each cell In rng
        Application.EnableEvents = False
'       Check to make sure update is row 4 or higher
        If cell.Row >= 4 Then
'           Update appropriate cells
            Select Case Target.Value
                Case "Ongoing"
                    Target.Offset(0, 1) = Now()
                Case "Completed"
                    Target.Offset(0, 2) = Now()
            End Select
        End If
        Application.EnableEvents = True
    Next cell
   
End Sub

Note that because your code errored out mid-stream, events were disabled, and not turned back on. So your code will not run automatically again until you turn events back on.
You can do that by manually running this macro once:
VBA Code:
Sub ReEnableEvents()
    Application.EnableEvents = True
End Sub
sorted, thank you so much
 
Upvote 0

Forum statistics

Threads
1,223,268
Messages
6,171,100
Members
452,379
Latest member
IainTru

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