summary
here is the summary of it:
1st: use the following code to create a new module, call it (dAuditTrail):
2nd: in your table, create a new memo field, call it (AuditTrail).
3rd: in your form add the new memo field, call it (tbAuditTrail) and make it 'Locked'.
4th: in the BeforeUpdate event of the form, write the following code:
i hope i didn't miss any part ^^"..
BUT, if you have a form with a subForm, do all the above and the following changes:
http://www.access-programmers.co.uk/forums/showpost.php?p=173439&postcount=15
but instead of 'frm', write 'MyForm' and it should work.
and if the parent form is based on more than one table, do the following changes:
http://www.access-programmers.co.uk/forums/showpost.php?p=713245&postcount=171
I attached the sample provided by ghudson with the required changes in the module, and added a form with subForm with the Audit Trail, I hope it helps ^^..
and yes, THANKS everyone for this nice discussion and the ones who helped for your help.
here is the summary of it:
1st: use the following code to create a new module, call it (dAuditTrail):
Code:
Option Compare Database
Option Explicit
Public Function Audit_Trail()
On Error GoTo Err_Audit_Trail
'ACC2000: How to Create an Audit Trail of Record Changes in a Form
'http://support.microsoft.com/default.aspx?scid=kb;en-us;197592
Dim MyForm As Form
Dim ctl As Control
Dim sUser As String
Set MyForm = Screen.ActiveForm
' sUser = "User: " & UsersID 'You need to identify your users if you are not using Access security with workgroups.
' sUser = Environ("UserName") 'get the users login name
sUser = CurrentUser '=Admin if you are not using Access security with user workgroups and permissions
'If new record, record it in audit trail and exit function.
If MyForm.NewRecord = True Then
MyForm!AuditTrail = MyForm!tbAuditTrail & "New Record added on " & Now & " by " & sUser & ";"
Exit Function
End If
'Set date and current user if the form (current record) has been modified.
MyForm!AuditTrail = MyForm!tbAuditTrail & vbCrLf & vbLf & "Changes made on " & Now & " by " & sUser & ";"
'Check each data entry control for change and record old value of the control.
For Each ctl In MyForm.Controls
'Only check data entry type controls.
Select Case ctl.ControlType
Case acTextBox, acComboBox, acListBox, acOptionGroup, acCheckBox
If ctl.Name = "tbAuditTrail" Then GoTo TryNextControl 'Skip AuditTrail field.
'If new and old value do not equal
If ctl.Value <> ctl.OldValue Then
MyForm!AuditTrail = MyForm!tbAuditTrail & vbCrLf & ctl.Name & ": Changed From: " & ctl.OldValue & ", To: " & ctl.Value
'If old value is Null and new value is not Null
ElseIf IsNull(ctl.OldValue) And Len(ctl.Value) > 0 Or ctl.OldValue = "" And Len(ctl.Value) > 0 Then
MyForm!AuditTrail = MyForm!tbAuditTrail & vbCrLf & ctl.Name & ": Was Previoulsy Null, New Value: " & ctl.Value
'If new value is Null and old value is not Null
ElseIf IsNull(ctl.Value) And Len(ctl.OldValue) > 0 Or ctl.Value = "" And Len(ctl.OldValue) > 0 Then
MyForm!AuditTrail = MyForm!tbAuditTrail & vbCrLf & ctl.Name & ": Changed From: " & ctl.OldValue & ", To: Null"
End If
End Select
TryNextControl:
Next ctl
Exit_Audit_Trail:
Exit Function
Err_Audit_Trail:
If Err.Number = 64535 Then 'Operation is not supported for this type of object.
Exit Function
ElseIf Err.Number = 2475 Then 'You entered an expression that requires a form to be the active window
Beep
MsgBox "A form is required to be the active window!", vbCritical, "Invalid Active Window"
Else
Beep
MsgBox Err.Number & " - " & Err.Description
End If
Resume Exit_Audit_Trail
End Function
3rd: in your form add the new memo field, call it (tbAuditTrail) and make it 'Locked'.
4th: in the BeforeUpdate event of the form, write the following code:
Code:
Private Sub Form_BeforeUpdate(Cancel As Integer)
On Error GoTo Form_BeforeUpdate_Err
Call Audit_Trail
Form_BeforeUpdate_Exit:
Exit Sub
Form_BeforeUpdate_Err:
MsgBox Err.Number & " - " & Err.Description
Resume Form_BeforeUpdate_Exit
End Sub
BUT, if you have a form with a subForm, do all the above and the following changes:
http://www.access-programmers.co.uk/forums/showpost.php?p=173439&postcount=15
but instead of 'frm', write 'MyForm' and it should work.
and if the parent form is based on more than one table, do the following changes:
http://www.access-programmers.co.uk/forums/showpost.php?p=713245&postcount=171
I attached the sample provided by ghudson with the required changes in the module, and added a form with subForm with the Audit Trail, I hope it helps ^^..
and yes, THANKS everyone for this nice discussion and the ones who helped for your help.
Attachments
Last edited: