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

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
Welcome to the Board!

I don't think you are going to be able to use Excel formulas to do what you want. The issue is that NOW() will always return the current day/time.
It is NOT a static value, so you won't catch/freeze the point in time that value was changed.
Every time you open you workbook, any cells returning a value will return the current date/time.

You will need to use DateStamp logic via VBA. You can watch a specified range, and when someone manually changes a value, you can capture the precise date/time (and freeze it).

So, a few questions for you:
1. Is column M being updated manually?
2. For column N, do you want to capture the date/time when the value in column M is manually changed to "Ongoing"?
3. For column O, do you want to capture the date/time when the value in column M is manually changed to "Completed"?
4. Does the data start on row 4, or some other row?
 
Upvote 0
If all my assumptions are correct, here is VBA code that will do what you want.
In order for this to run automatically, it MUST be placed in the proper Sheet module in VBA.
Here is an easy way to make sure you put it in the correct place.
- Go to the sheet in Excel that you want to apply this to (the sheet with your data)
- Right-click on the sheet tab name at the bottom of the screen
- Select "View Code"
- Paste the following code in the VB Editor window that opens up
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

    Dim rng As Range, cell As Range
    
'   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
 
Upvote 0
Solution
Welcome to the Board!

I don't think you are going to be able to use Excel formulas to do what you want. The issue is that NOW() will always return the current day/time.
It is NOT a static value, so you won't catch/freeze the point in time that value was changed.
Every time you open you workbook, any cells returning a value will return the current date/time.

You will need to use DateStamp logic via VBA. You can watch a specified range, and when someone manually changes a value, you can capture the precise date/time (and freeze it).

So, a few questions for you:
1. Is column M being updated manually?
2. For column N, do you want to capture the date/time when the value in column M is manually changed to "Ongoing"?
3. For column O, do you want to capture the date/time when the value in column M is manually changed to "Completed"?
4. Does the data start on row 4, or some other row?
Hi,

i did think that NOW() would be a problem, but i dont mind removing this to enable the above to function correctly. In response to your questions -

1. Is column M being updated manually? - yes this is updated manually by the operator
2. For column N, do you want to capture the date/time when the value in column M is manually changed to "Ongoing"? Yes
3. For column O, do you want to capture the date/time when the value in column M is manually changed to "Completed"? Yes
4. Does the data start on row 4, or some other row? yeh the data starts on row 4 - there are merged cells seperating the differing task groups, see screenshot.

1649941008705.png


Thank you so much for your quick response :)
 
Upvote 0
Based on your answers, I think the code I provided in my previous post should work for you.
Give it a try and let us know how it works.
 
Upvote 0
Based on your answers, I think the code I provided in my previous post should work for you.
Give it a try and let us know how it works.
This works perfect, Thank you so much.

im sure this will be the first of many questions i will have regarding this sheet. Thank you
 
Upvote 0
You are welcome.
Glad I was able to help!
:)
 
Upvote 0
You are welcome.
Glad I was able to help!
:)
i back again, sorry.

it is probably something i am doing but i am now getting a Run Time error 13 - type mismatch.

im trying to reset the page to be blank ready to use as a template - when i click play in VBA it keeps giving me the error
 
Upvote 0
i back again, sorry.

it is probably something i am doing but i am now getting a Run Time error 13 - type mismatch.

im trying to reset the page to be blank ready to use as a template - when i click play in VBA it keeps giving me the error
1649942951160.png
 
Upvote 0
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
 
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