Macro to track changes to multiple cells

MRSHCL

New Member
Joined
Nov 29, 2022
Messages
4
Office Version
  1. 365
Platform
  1. Windows
I have an Excel macro which is designed to create a new Excel tab ("Tracker") where changes made to any worksheet within the workbook are recorded, detailing "Cell Changed", "Old Value", "New Value", "Old Formula", "New Formula", "Time of Change", "Date of Change", and "User".

The macro currently will not detail the "Old Value" of the change where the target of the change are multiple cells, and instead shows as "Multiple Cells Selected" in the Tracker tab.

From what I can deduce, I need the declared variable "vOldValue" to equal a string created from the values from the selection, however I don't know how to achieve this.

Please see macro code below:

VBA Code:
Option Explicit
Dim sOldAddress As String
Dim vOldValue As Variant
Dim sOldFormula As String
 
Private Sub Workbook_TrackChange(Cancel As Boolean)
     
     
    Dim sh As Worksheet
    For Each sh In ActiveWorkbook.Worksheets
        sh.PageSetup.LeftFooter = "&06" & ActiveWorkbook.FullName & vbLf & "&A"
    Next sh
End Sub
 
Private Sub Workbook_SheetChange(ByVal sh As Object, ByVal Target As Range)
     '''''''''''''''''''''''''''''''''''''''''''''
     'lenze 2003(http://vbaexpress.com/kb/getarticle.php?kb_id=909)
     'Colin_L 2009 (http://www.mrexcel.com/forum/showthread.php?t=376400&referrerid=76744)
     'Mark Reierson 2009 (http://www.vbaexpress.com/kb/getarticle.php?kb_id=1074)

     '''''''''''''''''''''''''''''''''''''''''''''
     
    Dim wSheet As Worksheet
    Dim wActSheet As Worksheet
    Dim iCol As Integer
    Set wActSheet = ActiveSheet
     
     'Precursor Exits
     'Other conditions that you do not want to tracke could be added here
    'If vOldValue = "" Then Exit Sub 'If you comment out this line *every* entry will be recorded
     
     'Continue
     
    On Error Resume Next ' This Error-Resume-Next is only to allow the creation of the tracker sheet.
    Set wSheet = Sheets("Tracker")
     '**** Add the tracker Sheet if it does not exist ****
     
    If wSheet Is Nothing Then
        Set wActSheet = ActiveSheet
        Worksheets.Add(After:=Worksheets(Worksheets.Count)).Name = "Tracker"
    End If
    On Error GoTo 0
     '**** End of specific error resume next
     
    On Error GoTo ErrorHandler
    With Application
        .ScreenUpdating = False
        .EnableEvents = False
    End With
     
    With Sheets("Tracker")
         '******** This bit of code moves the tracker over a column when the first columns are full**'
        If .Cells(1, 1) = "" Then '
            iCol = 1 '
        Else '
            iCol = .Cells(1, 256).End(xlToLeft).Column - 7 '
            If Not .Cells(65536, iCol) = "" Then '
                iCol = .Cells(1, 256).End(xlToLeft).Column + 1 '
            End If '
        End If '
         '********* END *****************************************************************************'
        .Unprotect Password:="Secret"
         
         '******** Sets the Column Headers **********************************************************
        If LenB(.Cells(1, iCol).Value) = 0 Then
            .Range(.Cells(1, iCol), .Cells(1, iCol + 7)) = Array("Cell Changed", "Old Value", _
            "New Value", "Old Formula", "New Formula", "Time of Change", "Date of Change", "User")
            .Cells.Columns.AutoFit
        End If
         
        With .Cells(.Rows.Count, iCol).End(xlUp).Offset(1)
             
            .Value = sOldAddress
             
            .Offset(0, 1).Value = vOldValue
            .Offset(0, 3).Value = sOldFormula
             
            If Target.Count = 1 Then
                .Offset(0, 2).Value = Target.Value
                If Target.HasFormula Then .Offset(0, 4).Value = "'" & Target.Formula
            End If
             
            .Offset(0, 5) = Time
            .Offset(0, 6) = Date
            .Offset(0, 7) = Application.UserName
            '.Offset(0, 7).Borders(xlEdgeRight).LineStyle = xlContinuous 'Adds a line at the end of the row
        End With
         
         '.Protect Password:="Secret"  'Uncomment to protect the "tracker tab"
         
    End With
ErrorExit:
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
    End With
     
    wActSheet.Activate
    Exit Sub
     
ErrorHandler:
     'any error handling you want
     'Debug.Print "We have an error"
    Resume ErrorExit
     
End Sub
 
Private Sub Workbook_SheetSelectionChange(ByVal sh As Object, ByVal Target As Range)
     
    With Target
        sOldAddress = .Address(external:=True)
         
        If .Count > 1 Then
            
            vOldValue = "Multiple Cells Selected" '???? Change this to get value of each cell selected before the change ????
            sOldFormula = vbNullString
             
        Else
             
            vOldValue = .Value
            If .HasFormula Then
                sOldFormula = "'" & Target.Formula
            Else
                sOldFormula = vbNullString
            End If
        End If
    End With
End Sub

Any assistance would be greatly appreciated.

Thank you.
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
Try this. HTH
VBA Code:
Private Sub Workbook_SheetSelectionChange(ByVal sh As Object, ByVal Target As Range)
     
    With Target
        sOldAddress = .Address(external:=True)
        Dim e, i
        If .Count > 1 Then
            For Each e In .Areas
                For Each i In e.Value
                    If vOldValue = "" Then
                        vOldValue = i
                    Else
                        vOldValue = vOldValue & "," & i
                    End If
                Next i
            Next e
            'vOldValue = "Multiple Cells Selected" '???? Change this to get value of each cell selected before the change ????
            sOldFormula = vbNullString
             
        Else
             
            vOldValue = .Value
            If .HasFormula Then
                sOldFormula = "'" & Target.Formula
            Else
                sOldFormula = vbNullString
            End If
        End If
    End With
End Sub
 
Upvote 0
Add one line to fix a bug of having more then one area.
VBA Code:
Private Sub Workbook_SheetSelectionChange(ByVal sh As Object, ByVal Target As Range)
    
    With Target
        sOldAddress = .Address(external:=True)
        Dim e, i
        If .Count > 1 Then
            vOldValue = ""      'add this to fix a bug of having more then one area.
            For Each e In .Areas
                For Each i In e.Value
                    If vOldValue = "" Then
                        vOldValue = i
                    Else
                        vOldValue = vOldValue & "," & i
                    End If
                Next i
            Next e
            'vOldValue = "Multiple Cells Selected" '???? Change this to get value of each cell selected before the change ????
            sOldFormula = vbNullString
             
        Else
             
            vOldValue = .Value
            If .HasFormula Then
                sOldFormula = "'" & Target.Formula
            Else
                sOldFormula = vbNullString
            End If
        End If
    End With
End Sub
 
Upvote 0
Your code is really interesting.
So I take a while to work on it.
If you don't mind, try this.
VBA Code:
'Option Explicit
Dim sOldAddress As String
Dim vOldValue As Variant
Dim sOldFormula As String
 
'Private Sub Workbook_TrackChange(Cancel As Boolean)
'
'
'    Dim sh As Worksheet
'    For Each sh In ActiveWorkbook.Worksheets
'        sh.PageSetup.LeftFooter = "&06" & ActiveWorkbook.FullName & vbLf & "&A"
'    Next sh
'End Sub
 
Private Sub Workbook_SheetChange(ByVal sh As Object, ByVal Target As Range)
     '''''''''''''''''''''''''''''''''''''''''''''
     'lenze 2003(http://vbaexpress.com/kb/getarticle.php?kb_id=909)
     'Colin_L 2009 (http://www.mrexcel.com/forum/showthread.php?t=376400&referrerid=76744)
     'Mark Reierson 2009 (http://www.vbaexpress.com/kb/getarticle.php?kb_id=1074)

     '''''''''''''''''''''''''''''''''''''''''''''
    If sh.Name = "Tracker" Then Exit Sub
    Dim wSheet As Worksheet
    Dim wActSheet As Worksheet
    Dim iCol As Integer
    Set wActSheet = ActiveSheet
     
     'Precursor Exits
     'Other conditions that you do not want to tracke could be added here
    'If vOldValue = "" Then Exit Sub 'If you comment out this line *every* entry will be recorded
     
     'Continue
     
    On Error Resume Next ' This Error-Resume-Next is only to allow the creation of the tracker sheet.
    Set wSheet = Sheets("Tracker")
     '**** Add the tracker Sheet if it does not exist ****
     
    If wSheet Is Nothing Then
        Set wActSheet = ActiveSheet
        Worksheets.Add(After:=Worksheets(Worksheets.Count)).Name = "Tracker"
    End If
    On Error GoTo 0
     '**** End of specific error resume next
     
    On Error GoTo ErrorHandler
    With Application
        .ScreenUpdating = False
        .EnableEvents = False
    End With
     
    With Sheets("Tracker")
         '******** This bit of code moves the tracker over a column when the first columns are full**'
        If .Cells(1, 1) = "" Then '
            iCol = 1 '
        Else '
            iCol = .Cells(1, 256).End(xlToLeft).Column - 7 '
            If Not .Cells(65536, iCol) = "" Then '
                iCol = .Cells(1, 256).End(xlToLeft).Column + 1 '
            End If '
        End If '
         '********* END *****************************************************************************'
        .Unprotect Password:="Secret"
         
         '******** Sets the Column Headers **********************************************************
        If LenB(.Cells(1, iCol).Value) = 0 Then
            .Range(.Cells(1, iCol), .Cells(1, iCol + 7)) = Array("Cell Changed", "Old Value", _
            "New Value", "Old Formula", "New Formula", "Time of Change", "Date of Change", "User")
            .Cells.Columns.AutoFit
        End If
         
        With .Cells(.Rows.Count, iCol).End(xlUp).Offset(1)
             
            .Value = sOldAddress
             
            .Offset(0, 1).Value = vOldValue
            .Offset(0, 3).Value = sOldFormula
             sOldFormula = ""
            If Range(sOldAddress).Count = 1 Then
                .Offset(0, 2).Value = Target.Value
                If Target.HasFormula Then .Offset(0, 4).Value = "'" & Target.Formula
            Else
                Dim e, i, tmp
                On Error Resume Next
                    For Each e In Range(sOldAddress).Areas
                        For Each i In e
                            If tmp = "" Then
                                If i = "" Then
                                    tmp = " "
                                    sbHasFormula (i)
                                Else
                                    tmp = i
                                    sbHasFormula (i)
                                End If
                            Else
                                tmp = tmp & "," & i
                                sbHasFormula (i)
                            End If
                        Next i
                    Next e
                tmp = Trim(tmp)
                .Offset(0, 2).Value = tmp
                .Offset(0, 4) = sOldFormula
             End If
             
            .Offset(0, 5) = Time
            .Offset(0, 6) = Date
            .Offset(0, 7) = Application.UserName
            '.Offset(0, 7).Borders(xlEdgeRight).LineStyle = xlContinuous 'Adds a line at the end of the row
        End With
         
         '.Protect Password:="Secret"  'Uncomment to protect the "tracker tab"
         
    End With
ErrorExit:
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
    End With
     
    wActSheet.Activate
    Exit Sub
     
ErrorHandler:
     'any error handling you want
     'Debug.Print "We have an error"
    Resume ErrorExit
     
End Sub
 
Private Sub Workbook_SheetSelectionChange(ByVal sh As Object, ByVal Target As Range)
    If sh.Name = "Tracker" Then Exit Sub
  
    With Target
        sOldAddress = .Address(external:=True)
        Dim e, i
        If .Count > 1 Then
            vOldValue = ""
            sOldFormula = ""
            On Error Resume Next
            For Each e In .Areas
                For Each i In e
                    If vOldValue = "" Then
                        If i = "" Then
                            vOldValue = " "
                            sbHasFormula (i)
                        Else
                            vOldValue = i
                            sbHasFormula (i)
                        End If
                    Else
                        vOldValue = vOldValue & "," & i
                        sbHasFormula (i)
                    End If
                Next i
            Next e
            vOldValue = Trim(vOldValue)
            'vOldValue = "Multiple Cells Selected" '???? Change this to get value of each cell selected before the change ????
            'sOldFormula = vbNullString
             
        Else
             
            vOldValue = .Value
            If .HasFormula Then
                sOldFormula = "'" & Target.Formula
            Else
                sOldFormula = vbNullString
            End If
        End If
    End With
End Sub

Sub sbHasFormula(ByVal Target As Range)
    If Target.HasFormula Then
        If sOldFormula = "" Then
            sOldFormula = "'" & Target.Formula
        Else
            sOldFormula = sOldFormula & "||" & Target.Formula
        End If
    End If
End Sub
 
Upvote 0
Your code is really interesting.
So I take a while to work on it.
If you don't mind, try this.
VBA Code:
'Option Explicit
Dim sOldAddress As String
Dim vOldValue As Variant
Dim sOldFormula As String
 
'Private Sub Workbook_TrackChange(Cancel As Boolean)
'
'
'    Dim sh As Worksheet
'    For Each sh In ActiveWorkbook.Worksheets
'        sh.PageSetup.LeftFooter = "&06" & ActiveWorkbook.FullName & vbLf & "&A"
'    Next sh
'End Sub
 
Private Sub Workbook_SheetChange(ByVal sh As Object, ByVal Target As Range)
     '''''''''''''''''''''''''''''''''''''''''''''
     'lenze 2003(http://vbaexpress.com/kb/getarticle.php?kb_id=909)
     'Colin_L 2009 (http://www.mrexcel.com/forum/showthread.php?t=376400&referrerid=76744)
     'Mark Reierson 2009 (http://www.vbaexpress.com/kb/getarticle.php?kb_id=1074)

     '''''''''''''''''''''''''''''''''''''''''''''
    If sh.Name = "Tracker" Then Exit Sub
    Dim wSheet As Worksheet
    Dim wActSheet As Worksheet
    Dim iCol As Integer
    Set wActSheet = ActiveSheet
    
     'Precursor Exits
     'Other conditions that you do not want to tracke could be added here
    'If vOldValue = "" Then Exit Sub 'If you comment out this line *every* entry will be recorded
    
     'Continue
    
    On Error Resume Next ' This Error-Resume-Next is only to allow the creation of the tracker sheet.
    Set wSheet = Sheets("Tracker")
     '**** Add the tracker Sheet if it does not exist ****
    
    If wSheet Is Nothing Then
        Set wActSheet = ActiveSheet
        Worksheets.Add(After:=Worksheets(Worksheets.Count)).Name = "Tracker"
    End If
    On Error GoTo 0
     '**** End of specific error resume next
    
    On Error GoTo ErrorHandler
    With Application
        .ScreenUpdating = False
        .EnableEvents = False
    End With
    
    With Sheets("Tracker")
         '******** This bit of code moves the tracker over a column when the first columns are full**'
        If .Cells(1, 1) = "" Then '
            iCol = 1 '
        Else '
            iCol = .Cells(1, 256).End(xlToLeft).Column - 7 '
            If Not .Cells(65536, iCol) = "" Then '
                iCol = .Cells(1, 256).End(xlToLeft).Column + 1 '
            End If '
        End If '
         '********* END *****************************************************************************'
        .Unprotect Password:="Secret"
        
         '******** Sets the Column Headers **********************************************************
        If LenB(.Cells(1, iCol).Value) = 0 Then
            .Range(.Cells(1, iCol), .Cells(1, iCol + 7)) = Array("Cell Changed", "Old Value", _
            "New Value", "Old Formula", "New Formula", "Time of Change", "Date of Change", "User")
            .Cells.Columns.AutoFit
        End If
        
        With .Cells(.Rows.Count, iCol).End(xlUp).Offset(1)
            
            .Value = sOldAddress
            
            .Offset(0, 1).Value = vOldValue
            .Offset(0, 3).Value = sOldFormula
             sOldFormula = ""
            If Range(sOldAddress).Count = 1 Then
                .Offset(0, 2).Value = Target.Value
                If Target.HasFormula Then .Offset(0, 4).Value = "'" & Target.Formula
            Else
                Dim e, i, tmp
                On Error Resume Next
                    For Each e In Range(sOldAddress).Areas
                        For Each i In e
                            If tmp = "" Then
                                If i = "" Then
                                    tmp = " "
                                    sbHasFormula (i)
                                Else
                                    tmp = i
                                    sbHasFormula (i)
                                End If
                            Else
                                tmp = tmp & "," & i
                                sbHasFormula (i)
                            End If
                        Next i
                    Next e
                tmp = Trim(tmp)
                .Offset(0, 2).Value = tmp
                .Offset(0, 4) = sOldFormula
             End If
            
            .Offset(0, 5) = Time
            .Offset(0, 6) = Date
            .Offset(0, 7) = Application.UserName
            '.Offset(0, 7).Borders(xlEdgeRight).LineStyle = xlContinuous 'Adds a line at the end of the row
        End With
        
         '.Protect Password:="Secret"  'Uncomment to protect the "tracker tab"
        
    End With
ErrorExit:
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
    End With
    
    wActSheet.Activate
    Exit Sub
    
ErrorHandler:
     'any error handling you want
     'Debug.Print "We have an error"
    Resume ErrorExit
    
End Sub
 
Private Sub Workbook_SheetSelectionChange(ByVal sh As Object, ByVal Target As Range)
    If sh.Name = "Tracker" Then Exit Sub
 
    With Target
        sOldAddress = .Address(external:=True)
        Dim e, i
        If .Count > 1 Then
            vOldValue = ""
            sOldFormula = ""
            On Error Resume Next
            For Each e In .Areas
                For Each i In e
                    If vOldValue = "" Then
                        If i = "" Then
                            vOldValue = " "
                            sbHasFormula (i)
                        Else
                            vOldValue = i
                            sbHasFormula (i)
                        End If
                    Else
                        vOldValue = vOldValue & "," & i
                        sbHasFormula (i)
                    End If
                Next i
            Next e
            vOldValue = Trim(vOldValue)
            'vOldValue = "Multiple Cells Selected" '???? Change this to get value of each cell selected before the change ????
            'sOldFormula = vbNullString
            
        Else
            
            vOldValue = .Value
            If .HasFormula Then
                sOldFormula = "'" & Target.Formula
            Else
                sOldFormula = vbNullString
            End If
        End If
    End With
End Sub

Sub sbHasFormula(ByVal Target As Range)
    If Target.HasFormula Then
        If sOldFormula = "" Then
            sOldFormula = "'" & Target.Formula
        Else
            sOldFormula = sOldFormula & "||" & Target.Formula
        End If
    End If
End Sub
The code isn't working for me, I'm not sure why. I just copy and pasted it, so it might be formatting issue on my end. Is there something I should be un-commenting?
 
Upvote 0
I have downloaded the file, however even this is not working for me.

I now suspect the issue is security config on my network (I am not an admin).

I will contact my administrator to see if this is the issue.
 
Upvote 0
Working now.

It was my network that was preventing the macro running.

Thank you so much!
 
Upvote 0
Maybe you can try my excel file directly.
track.xlsm (27.89KB) - SendSpace.com
Hello @HongRu,
Both file and script work like a charm on my machine.
I am trying to include a MsgBox that would pop every time a value is changed in my workbook, to prompt user to record the reason why the value was changed. This "Reason" would then be recorded on the "Tracker" worksheet.

I had a similar thing set up in another Macro (see sample below).
Yet for some reason I can't seem to figure out how to include this in your masterpiece. Would you be so kind as to lend me a hand on this?


VBA Code:
Dim wsLOE As Worksheet, wsTrail As Worksheet
Dim PreviousValue As Variant
Dim RowInsertion As Long
Dim Cellpos As Variant
Dim Frompos As Variant
Dim onpos As Variant
Dim dashpos As Variant
Dim Completion As VbMsgBoxResult
Dim Reasonbox As String
'Lines below prevent from selecting more than one cell at a time
'source https://forum.ozgrid.com/forum/index.php?thread/37445-prevent-multiple-cells-selection-delete-value/
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
    '>> Prevent user from multiple selection before any changes:
    
    If Selection.Cells.Count > 1 Then
        MsgBox "Sorry, multiple selections are not allowed.", vbCritical
        ActiveCell.Select
        Exit Sub
    End If
    
End Sub

Private Sub Worksheet_Change(ByVal Target As Range)
    
    Set wsTrail = ThisWorkbook.Worksheets("Trail")
    Set wsLOE = ActiveSheet
    
       If Target.Value <> PreviousValue Then
            
            Call Log_Change(Target)
                
    End If

End Sub

Private Sub Log_Change(ByVal Cell_Target As Range)
    RowInsertion = wsTrail.Cells(Rows.Count, "A").End(xlUp).Row + 1
        wsTrail.Cells(RowInsertion, "A").Value = _
        Application.UserName & " changed Cell " & Cell_Target.Address(False, False) _
        & " From (" & PreviousValue & ") to (" & Cell_Target.Value _
        & ") on " & ActiveSheet.Name & " Worksheet - " & Format(Now, "Ddd dd Mmm yyyy HH:mm:ss")
    wsTrail.Cells(RowInsertion, "A").Characters().Font.ColorIndex = 5
    'lines below look for the position of a word in the cell added in the audit trail
    Cellpos = InStr(1, wsTrail.Cells(RowInsertion, "A"), " Cell ")
    Frompos = InStr(1, wsTrail.Cells(RowInsertion, "A"), " From ")
    
    'lines below define red as the color of the test between two positions defined above
    wsTrail.Cells(RowInsertion, "A").Characters(Cellpos + 5, Frompos - Cellpos - 5).Font.Color = vbRed
    wsTrail.Cells(RowInsertion, "A").Characters(1, Cellpos - 9).Font.Color = vbRed
    
    

'line below calls a module to color in red content between parentheses
   Application.Run ("ChgTxtColor")

'lines below generates an Inputbox to record reason for change
Reasonbox = InputBox("Please enter the reason for the change : ", "Reason for change")
    If StrPtr(Reasonbox) = 0 Then
           Debug.Print "Cancel or ESC pressed"
               
        ElseIf Reasonbox = "" Then
           Debug.Print "OK pressed, No value entered, No default value"
               
        Else
            Debug.Print "OK pressed, Value entered or a Default value"
    End If
'line below prints answer to Inputbox in the column neighboring the audit trail information
    wsTrail.Cells(RowInsertion, "a").Offset(0, 1).Value = Reasonbox

'line below displays a completion message in a pop-up
Completion = MsgBox("Audit trail successfully updated", vbOKOnly)
End Sub


Private Sub Worksheet_Deactivate()
    
    Set wsLOE = Nothing
    Set wsTrail = Nothing

End Sub
 
Upvote 0

Forum statistics

Threads
1,215,059
Messages
6,122,916
Members
449,093
Latest member
dbomb1414

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