ACC2000: Controlling Bound Form Transactions in Access ProjectsID: Q200880
|
This article describes how you can control transactions in a form based on a SQL Server in a Microsoft Access project (.adp) file.
Typically, a developer needs to be able to let users of a database application commit all or none of their data changes on a form. Microsoft Access 97 and earlier did not provide this capability because transactions in bound forms were handled in a separate workspace controlled by Access.
However, in Access 2000, a developer can use a combination of ActiveX Data Objects (ADO) and the new form Recordset property to provide this capability. The example in this article assumes that the user wants to be prompted to commit all changes made to the form's data when the user closes the form. At that time, the user can either commit all of the changes or none of the changes.
Microsoft provides programming examples for illustration only, without warranty
either expressed or implied, including, but not limited to, the implied warranties of
merchantability and/or fitness for a particular purpose. This article assumes that you
are familiar with the programming language being demonstrated and the tools used to
create and debug procedures. Microsoft support professionals can help explain the functionality
of a particular procedure, but they will not modify these examples to provide added
functionality or construct procedures to meet your specific needs. If you have limited
programming experience, you may want to contact a Microsoft Certified Solution Provider
or the Microsoft fee-based consulting line at (800) 936-5200. For more information about
Microsoft Certified Solution Providers, please see the following page on the World Wide Web:
http://www.microsoft.com/mcsp/For more information about the support options available from Microsoft, please see the following page on the World Wide Web:
http://www.microsoft.com/support/supportnet/overview/overview.aspThe sample code in this article uses Microsoft ActiveX Data Objects. For this code to run properly, you need to reference the Microsoft ActiveX Data Objects 2.1 Library.
Option Compare Database
Option Explicit
Private boolFrmDirty As Boolean
Private boolFrmSaved As Boolean
Private adoConnection As New ADODB.Connection
Private adoRecordset As New ADODB.Recordset
Private Sub Form_AfterDelConfirm(Status As Integer)
If Me.Saved = False Then Me.Saved = (Status = acDeleteOK)
End Sub
Private Sub Form_AfterUpdate()
Me.Saved = True
End Sub
Private Sub Form_Delete(Cancel As Integer)
If Me.Dirtied = False Then adoConnection.BeginTrans
Me.Dirtied = True
End Sub
Private Sub Form_Dirty(Cancel As Integer)
If Me.Dirtied = False Then adoConnection.BeginTrans
Me.Dirtied = True
End Sub
Private Sub Form_Open(Cancel As Integer)
Dim strConnect As String
' You will need to modify the following string so the
' Server Name, User ID, and Password are correct.
strConnect = "DATA PROVIDER=SQLOLEDB;DATA SOURCE=Myserver;" & _
"UID=sa;PWD=;DATABASE=Pubs"
adoConnection.Provider = "MSDataShape"
adoConnection.Open strConnect
adoRecordset.Open "SELECT * FROM Authors", adoConnection, _
adOpenKeyset, adLockOptimistic
Set Me.Recordset = adoRecordset
Me.UniqueTable = "Authors"
End Sub
Private Sub Form_Unload(Cancel As Integer)
Dim msg As Integer
If Me.Saved Then
msg = MsgBox("Do you want to commit all changes?", _
vbYesNoCancel)
Select Case msg
Case vbYes
adoConnection.CommitTrans
Case vbNo
adoConnection.RollbackTrans
Case vbCancel
Cancel = True
End Select
Else
If Me.Dirtied Then adoConnection.RollbackTrans
End If
End Sub
Public Property Get Dirtied() As Boolean
Dirtied = boolFrmDirty
End Property
Public Property Let Dirtied(ByVal boolNewValue As Boolean)
boolFrmDirty = boolNewValue
End Property
Public Property Get Saved() As Boolean
Saved = boolFrmSaved
End Property
Public Property Let Saved(ByVal boolNewValue As Boolean)
boolFrmSaved = boolNewValue
End Property
Additional query words: inf ado commit rollback
Keywords : kbdta AccessCS
Version : WINDOWS:2000
Platform : WINDOWS
Issue type : kbhowto
Last Reviewed: July 6, 1999