Macro to Audit Trail a Specific Sheet

legalhustler

Well-known Member
Joined
Jun 5, 2014
Messages
1,171
Office Version
  1. 365
Platform
  1. Windows
Hello VBA Gurus!

I want to keep a track of any changes (doesn't necessarily have to track any formatting changes) to a specific sheet in a separate sheet called "Log". I found the following code that almost does what I want but I would like to break the attributes in different columns instead of one cell. I need the following fields in this specific order:

1) Computer Name - currently it uses the Excel application name, but I need the computer name. I think code is supposed to use the Environ function to do that.
2) Cell - this is the cell that is being changed, should be relative cell reference like B2 and not $B$2
3) Previous Amount - should use "$" sign and comma for each number unit. For negatives it should be use the parenthesis format i.e. "$ (xxx,xxx).
4) Current Amount - See above. If the amount gets deleted then the current amount should show a blank.
5) Date - date of change i.e. 7/26/2021
6) Time - time of change i.e. 12:53 PM (no need to put the seconds)

VBA Code:
Dim PreviousValue

Private Sub Worksheet_Change(ByVal Target As Range)
If Target.Value <> PreviousValue Then
Sheets("Log").Cells(65000, 1).End(xlUp).Offset(1, 0).Value = _
Application.UserName & " changed cell " & Target.Address _
& " from " & PreviousValue & " to " & Target.Value & " at: " & Time & " on: " & Date
End If
End Sub

Private Sub Worksheet_SelectionChange(ByVal Target As Range)
PreviousValue = Target.Value
End Sub

Any help is appreciated. TIA!
 
Sorry for the confusion, I was only giving you the macro that was changing. The complete solution is included below. Remember to place this code in the worksheet that you are auditing's vbe area.

VBA Code:
Option Explicit
Option Base 1

Dim PreviousValue As Variant

Private Sub Worksheet_SelectionChange(ByVal t As Range)
    PreviousValue = t.Value
End Sub

Private Sub Worksheet_Change(ByVal Target As Range)
            Dim nxtRow As Long
           
            If Target.Cells.Count = 1 Then
                nxtRow = Worksheets("Log").Cells(Rows.Count, 1).End(xlUp).Row + 1
               
                If Target.Value <> PreviousValue Then
                    With Sheets("Log")
                        .Cells(nxtRow, 1).Value = Environ$("computername")
                        .Cells(nxtRow, 2).Value = Replace(Target.Address, "$", "")
                        With .Cells(nxtRow, 3)
                            .Value = PreviousValue
                            If InStr(1, CStr(.Value), ".", vbTextCompare) <> 0 Then
                                .NumberFormat = "$#,##0.00_);[Red]($#,##0.00)"
                            Else
                                .NumberFormat = "$#,##0_);[Red]($#,##0)"
                            End If
                        End With
                        If Target.Value = "" Then
                            .Cells(nxtRow, 4).Value = ""
                        Else
                            With .Cells(nxtRow, 4)
                                .Value = Target.Value
                                If InStr(1, CStr(.Value), ".", vbTextCompare) <> 0 Then
                                    .NumberFormat = "$#,##0.00_);[Red]($#,##0.00)"
                                Else
                                    .NumberFormat = "$#,##0_);[Red]($#,##0)"
                                End If
                            End With
                        End If
                        .Cells(nxtRow, 5).Value = DateSerial(Year(Now()), Month(Now()), Day(Now()))
                        With .Cells(nxtRow, 6)
                            .Value = TimeSerial(Hour(Now()), Minute(Now()), 0)
                            .NumberFormat = "hh:mm AM/PM"
                        End With
                    End With
                End If
            End If
End Sub
 
Upvote 0

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
Sorry for the confusion, I was only giving you the macro that was changing. The complete solution is included below. Remember to place this code in the worksheet that you are auditing's vbe area.

VBA Code:
Option Explicit
Option Base 1

Dim PreviousValue As Variant

Private Sub Worksheet_SelectionChange(ByVal t As Range)
    PreviousValue = t.Value
End Sub

Private Sub Worksheet_Change(ByVal Target As Range)
            Dim nxtRow As Long
        
            If Target.Cells.Count = 1 Then
                nxtRow = Worksheets("Log").Cells(Rows.Count, 1).End(xlUp).Row + 1
            
                If Target.Value <> PreviousValue Then
                    With Sheets("Log")
                        .Cells(nxtRow, 1).Value = Environ$("computername")
                        .Cells(nxtRow, 2).Value = Replace(Target.Address, "$", "")
                        With .Cells(nxtRow, 3)
                            .Value = PreviousValue
                            If InStr(1, CStr(.Value), ".", vbTextCompare) <> 0 Then
                                .NumberFormat = "$#,##0.00_);[Red]($#,##0.00)"
                            Else
                                .NumberFormat = "$#,##0_);[Red]($#,##0)"
                            End If
                        End With
                        If Target.Value = "" Then
                            .Cells(nxtRow, 4).Value = ""
                        Else
                            With .Cells(nxtRow, 4)
                                .Value = Target.Value
                                If InStr(1, CStr(.Value), ".", vbTextCompare) <> 0 Then
                                    .NumberFormat = "$#,##0.00_);[Red]($#,##0.00)"
                                Else
                                    .NumberFormat = "$#,##0_);[Red]($#,##0)"
                                End If
                            End With
                        End If
                        .Cells(nxtRow, 5).Value = DateSerial(Year(Now()), Month(Now()), Day(Now()))
                        With .Cells(nxtRow, 6)
                            .Value = TimeSerial(Hour(Now()), Minute(Now()), 0)
                            .NumberFormat = "hh:mm AM/PM"
                        End With
                    End With
                End If
            End If
End Sub
No worries - this is great! If I change a formula the pop up debug prompts, anyway for the code to disregard formula changes so the debug message doesn't show? Thank you.
 
Upvote 0
Which cells contain formulas that are causing the debug error? I have tried inputting and editing formulas and all seems to work.
 
Upvote 0
Yeah not getting an error when I modify the formula but if the formula returns an error like VALUE# then the debug message pops up, would be best if it didn't show. Thanks again.
 
Upvote 0
Okay this is probably my last request, I removed the gridlines and borders from the log sheet and would like to know if borders can be added dynamically to each cell for the 6 columns whenever a new row gets added to the log sheet?
 
Upvote 0

Forum statistics

Threads
1,214,978
Messages
6,122,549
Members
449,089
Latest member
davidcom

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