Advanced: Requires expert coding, interoperability, and multiuser
skills.
This article applies to a Microsoft Access database (.mdb) and to a
Microsoft Access project (.adp).
MORE INFORMATION
To bind a Microsoft Access form to a recordset, you must
set the
Recordset property of the form to a valid Data Access Objects (DAO) or ADO
Recordset object.
The
Recordset property was introduced in Microsoft Access 2000, and it allows
you to bind forms to either DAO or ADO
Recordset objects. However, forms in Access 2000 support updateability only
if the ADO connection is opened by using the MSDataShape and SQL Server OLEDB
providers.
For additional information about this
limitation in Access 2000, click the article number below to view the article
in the Microsoft Knowledge Base:
227053 ACC2000: Forms Based on ADO Recordsets Are Read-Only
In Microsoft Access 2002 or later, you can create
an updateable form that is bound to an ADO recordset that uses other OLEDB
providers. A form must meet several general requirements for the form to be
updateable when it is bound to an ADO recordset. These general requirements
are:
- The underlying ADO recordset must be updateable.
- The recordset must contain one or more fields that are
uniquely indexed, such as a table's primary key.
The other requirements for updateability vary between different
providers. This article describes what the other requirements are when you use
the Microsoft SQL Server, Jet, ODBC, and Oracle OLEDB providers.
Requirements for Microsoft SQL Server
There are two main requirements for supporting updateability when
you bind a form to an ADO recordset that is using Microsoft SQL Server
data:
- The ADO recordset's connection must use the Microsoft
Access 10.0 OLEDB provider as its service provider.
- The ADO recordset's connection must use the Microsoft SQL
Server OLEDB provider as its data provider.
NOTE: The Microsoft Access 10.0 OLEDB provider is an OLEDB service
provider that was written specifically for use in Microsoft Access. It was not
designed to be used in applications other than Microsoft Access, and it is not
supported in other applications.
When you create ADO recordsets
within Microsoft Access, you have a choice as to which ADO connection will be
used by the recordset. Your ADO code can share the ADO connection that
Microsoft Access is using for the SQL Server database currently open in an
Access project (ADP) file; or you can programmatically create a new ADO
connection to a different SQL Server database.
Sharing the ADO Connection Used by Microsoft Access
If you are using an Access project file (.adp) connected to a
Microsoft SQL Server database, it is possible for your ADO code to share the
ADO connection that Microsoft Access is using. This connection is exposed by
the
CurrentProject.AccessConnection property.
The following example demonstrates how to
bind a form to an ADO recordset that is based on SQL Server data that shares an
ADO connection with Microsoft Access.
- Open the sample project NorthwindCS.adp.
- Open the Customers form in Design view.
- Clear the RecordSource property of the form to unbind the form.
- Set the OnOpen property of the form to the following event procedure:
Private Sub Form_Open(Cancel As Integer)
Dim cn As ADODB.Connection
Dim rs As ADODB.Recordset
'Use the ADO connection that Access uses
Set cn = CurrentProject.AccessConnection
'Create an instance of the ADO Recordset class, and
'set its properties
Set rs = New ADODB.Recordset
With rs
Set .ActiveConnection = cn
.Source = "SELECT * FROM Customers"
.LockType = adLockOptimistic
.CursorType = adOpenKeyset
.Open
End With
'Set the form's Recordset property to the ADO recordset
Set Me.Recordset = rs
Set rs = Nothing
Set cn = Nothing
End Sub
- Save and then close the form.
- Open the Customers form in Form view.
- Add, edit, or delete a record in the form.
Note that the form is bound to an updateable recordset that is
based on SQL Server data.
Opening a Separate ADO Connection
At some point, you may have to open and manage your own ADO
connection to SQL Server. For example, you would have to use this approach if
you were writing your code in an Access database (.mdb) or an Access project
file (.adp) that was connected to a different SQL Server database than your
application. Note that when you use this approach, Microsoft recommends that
you close the ADO connection that you opened when it is no longer needed. For
example, you may want to close the ADO connection in the UnLoad event of the
form.
The following example demonstrates how to open your own ADO
connection to a Microsoft SQL Server database and to bind a form to it:
- Open the sample database Northwind.mdb.
- Open the Customers form in Design view.
- Clear the RecordSource property of the form to unbind the form.
- Set the OnOpen property of the form to the following event procedure:
Private Sub Form_Open(Cancel As Integer)
Dim cn As ADODB.Connection
Dim rs As ADODB.Recordset
'Create a new ADO Connection object
Set cn = New ADODB.Connection
'Use the Access 10 and SQL Server OLEDB providers to
'open the Connection
'You will need to replace MySQLServer with the name
'of a valid SQL Server
With cn
.Provider = "Microsoft.Access.OLEDB.10.0"
.Properties("Data Provider").Value = "SQLOLEDB"
.Properties("Data Source").Value = "MySQLServer"
.Properties("User ID").Value = "sa"
.Properties("Password").Value = ""
.Properties("Initial Catalog").Value = "NorthwindCS"
.Open
End With
'Create an instance of the ADO Recordset class, and
'set its properties
Set rs = New ADODB.Recordset
With rs
Set .ActiveConnection = cn
.Source = "SELECT * FROM Customers"
.LockType = adLockOptimistic
.CursorType = adOpenKeyset
.Open
End With
'Set the form's Recordset property to the ADO recordset
Set Me.Recordset = rs
Set rs = Nothing
Set cn = Nothing
End Sub
- Add the following code to the UnLoad event of the form:
Private Sub Form_Unload(Cancel As Integer)
'Close the ADO connection we opened
Dim cn As ADODB.Connection
Set cn = Me.Recordset.ActiveConnection
cn.Close
Set cn = Nothing
End Sub
- Save the form, and then close it.
- Open the Customers form in Form view.
- Add, edit, or delete a record in the form.
Note that the form is bound to an updateable recordset that is
based on SQL Server data.
Requirements for Microsoft Jet
Even though it is possible to bind a form to an ADO recordset
that is using data from a Jet database, Microsoft recommends that you use DAO
instead. DAO is highly optimized for Jet and typically performs faster than ADO
when used with a Jet database.
When you bind a form to an ADO
recordset using Microsoft Jet data, there are two alternatives:
- The recordset's ActiveConnection property must use the Microsoft Access 10.0 OLEDB service
provider, as well as the Microsoft Jet 4.0 OLEDB Data provider and the recordset must be a server-side cursor.
-or- - The recordset's ActiveConnection property must use only Microsoft Jet 4.0 OLEDB Data provider and the recordset must be a client-side cursor.
Similar to the "Microsoft SQL Server" section earlier in this
article, you have a choice as to which ADO connection will be used by the
recordset when using a Jet database. Your ADO code can share the ADO connection
that Microsoft Access is using for the Jet database file (.mdb) currently open,
or you can programmatically create a new ADO connection to a separate Jet
database file.
Sharing the ADO Connection Used by Microsoft Access
If you are writing the code in the same Microsoft Access database
(.mdb) that contains the data that your recordset needs, it is possible for
your ADO code to share the ADO connection that Microsoft Access is using. This
connection is exposed by the
CurrentProject.AccessConnection property. The following example demonstrates how to bind a form
to an ADO recordset in a Jet database by sharing the ADO connection that
Microsoft Access is currently using:
- Open the sample database Northwind.mdb.
- Open the Customers form in Design view.
- Clear the RecordSource property of the form to unbind the form.
- Set the OnOpen property of the form to the following event procedure:
Private Sub Form_Open(Cancel As Integer)
Dim cn As ADODB.Connection
Dim rs As ADODB.Recordset
Set cn = CurrentProject.AccessConnection
'Create an instance of the ADO Recordset class, and
'set its properties
Set rs = New ADODB.Recordset
With rs
Set .ActiveConnection = cn
.Source = "SELECT * FROM Customers"
.LockType = adLockOptimistic
.CursorType = adOpenKeyset
.CursorLocation = adUseServer
.Open
End With
'Set the form's Recordset property to the ADO recordset
Set Me.Recordset = rs
Set rs = Nothing
Set cn = Nothing
End Sub
- Save the form, and then close it.
- Open the Customers form in Form view.
- Add, edit, or delete a record in the form.
Note that the form is bound to an updateable recordset that is
using Jet data.
Opening a Separate ADO Connection
At some point, you may have to open and manage your own ADO
connection to a Jet database. For example, you would have to use this approach
if you are writing your code in a database that is separate from the database
that contains the data that you need to access. Note that when you use this
approach, Microsoft recommends that you close the ADO connection that you
opened when it is no longer needed. For example, you may want to close the ADO
connection in the UnLoad event of the form.
The following example
demonstrates how to open your own ADO connection to a Microsoft Jet database
and to bind a form to it:
- Create a new blank database.
- Import the Customers form from the sample database
Northwind.mdb.
- Open the Customers form in Design view.
- Clear the RecordSource property of the form to unbind form.
- Set the OnOpen property of the form to the following event procedure:
Private Sub Form_Open(Cancel As Integer)
Dim cn As ADODB.Connection
Dim rs As ADODB.Recordset
'Create a new ADO Connection object
Set cn = New ADODB.Connection
With cn
.Provider = "Microsoft.Access.OLEDB.10.0"
.Properties("Data Provider").Value = "Microsoft.Jet.OLEDB.4.0"
.Properties("Data Source").Value = _
"C:\Program Files\Microsoft Office\Office10" & _
"\Samples\Northwind.mdb"
.Open
End With
'Create an instance of the ADO Recordset class, and
'set its properties
Set rs = New ADODB.Recordset
With rs
Set .ActiveConnection = cn
.Source = "SELECT * FROM Customers"
.LockType = adLockOptimistic
.CursorType = adOpenKeyset
.Open
End With
'Set the form's Recordset property to the ADO recordset
Set Me.Recordset = rs
Set rs = Nothing
Set cn = Nothing
End Sub
- Add the following code to the UnLoad event of the form:
Private Sub Form_Unload(Cancel As Integer)
'Close the ADO connection we opened
Dim cn As ADODB.Connection
Set cn = Me.Recordset.ActiveConnection
cn.Close
Set cn = Nothing
End Sub
- Save the form, and then close it.
- Open the Customers form in Form view.
- Add, edit, or delete a record in the form.
Note that the form is bound to an updateable recordset that is
using Jet data.
Requirements for ODBC
When you bind a form to an ADO recordset that is using data from
an ODBC database, there are two main requirements:
- The ADO connection that is used by the recordset must use
the Microsoft OLEDB provider for ODBC.
- The ADO recordset must be a client-side cursor.
The following example demonstrates how to open an ADO
connection to an ODBC database and to bind a form to it.
NOTE: These steps assume that the ODBC database contains a table named
CUSTOMERS that is identical in structure to the Customers table in the sample
database Northwind.mdb. It also assumes you have created an ODBC DSN named
MyDSN that uses the ODBC driver that you need to connect to the back-end
database.
- Open the sample database Northwind.mdb.
- Open the Customers form in Design view.
- Clear the RecordSource property of the form to unbind form.
- Set the OnOpen property of the form to the following event procedure:
Private Sub Form_Open(Cancel As Integer)
Dim cn As ADODB.Connection
Dim rs As ADODB.Recordset
Dim strConnection As String
strConnection = "ODBC;DSN=MyDSN;UID=sa;PWD=;DATABASE=Northwind"
'Create a new ADO Connection object
Set cn = New ADODB.Connection
With cn
.Provider = "MSDASQL"
.Properties("Data Source").Value = strConnection
.Open
End With
'Create an instance of the ADO Recordset class, and
'set its properties
Set rs = New ADODB.Recordset
With rs
Set .ActiveConnection = cn
.Source = "SELECT * FROM Customers"
.LockType = adLockOptimistic
.CursorType = adOpenKeyset
.CursorLocation = adUseClient
.Open
End With
'Set the form's Recordset property to the ADO recordset
Set Me.Recordset = rs
Set rs = Nothing
Set cn = Nothing
End Sub
- Add the following code to the UnLoad event of the form:
Private Sub Form_Unload(Cancel As Integer)
'Close the ADO connection we opened
Dim cn As ADODB.Connection
Set cn = Me.Recordset.ActiveConnection
cn.Close
Set cn = Nothing
End Sub
- Save the form, and then close it.
- Open the Customers form in Form view.
- Add, edit, or delete a record in the form.
Note that the form is bound to an updateable recordset that is
based on ODBC data.
Requirements for Oracle
When you bind a form to an ADO recordset that is using data from
an Oracle database, there are two main requirements:
- The ADO connection that is used by the recordset must use
the Microsoft OLEDB provider for Oracle.
- The ADO Recordset must be a client-side cursor.
The following example demonstrates how to open an ADO
connection to an Oracle database and to bind a form to it.
NOTE: These steps assume that the Oracle database contains a table
named CUSTOMERS that is identical in structure to the Customers table in the
sample database Northwind.mdb.
- Open the sample database Northwind.mdb.
- Open the Customers form in Design view.
- Clear the RecordSource property of the form to unbind the form.
- Set the OnOpen property of the form to the following event procedure:
Private Sub Form_Open(Cancel As Integer)
Dim cn As ADODB.Connection
Dim rs As ADODB.Recordset
'Create a new ADO Connection object
Set cn = New ADODB.Connection
With cn
.Provider = "MSDAORA"
.Properties("Data Source").Value = "MyOracleServer"
.Properties("User ID").Value = "username"
.Properties("Password").Value = "password"
.Open
End With
'Create an instance of the ADO Recordset class, and
'set its properties
Set rs = New ADODB.Recordset
With rs
Set .ActiveConnection = cn
.Source = "SELECT * FROM Customers"
.LockType = adLockOptimistic
.CursorType = adOpenKeyset
.CursorLocation = adUseClient
.Open
End With
'Set the form's Recordset property to the ADO recordset
Set Me.Recordset = rs
Set rs = Nothing
Set cn = Nothing
End Sub
- Add the following code to the UnLoad event of the form:
Private Sub Form_Unload(Cancel As Integer)
'Close the ADO connection we opened
Dim cn As ADODB.Connection
Set cn = Me.Recordset.ActiveConnection
cn.Close
Set cn = Nothing
End Sub
- Save the form, and then close it.
- Open the Customers form in Form view.
- Add, edit, or delete a record in the form.
Note that the form is bound to an updateable recordset that is
based on Oracle data.