Updating data through a cursor

The ^ PRODUCT ^ lets you update a result set through a cursor. This capability is not available through the MSDASQL provider.

Updating record sets

You can update the database through a record set.

Private Sub Command6_Click()
   Dim myConn As New ADODB.Connection
   Dim myRS As New ADODB.Recordset
   Dim SQLString As String
   ' Connect
   myConn.Provider = "ASEOLEDB"
   myConn.ConnectionString = "Data Source=MANGO:5000;User ID=sa;Pwd=;"
   myConn.Open
   myConn.BeginTrans
   SQLString = "Select * from customer"
   myRS.Open SQLString, myConn, adOpenDynamic, adLockBatchOptimistic
   If myRS.BOF And myRS.EOF Then
      MsgBox "Recordset is empty!", 16, "Empty Recordset"
   Else
      MsgBox "Cursor type: " + CStr(myRS.CursorType), vbInformation
      myRS.MoveFirst
         For i = 1 To 3
            MsgBox "Row: " + CStr(myRS.Fields("id")), vbInformation
            If i = 2 Then
               myRS.Update "City", "Toronto"
               myRS.UpdateBatch
            End If
      myRS.MoveNext
      Next i '
      myRS.Close
   End If
   myConn.CommitTrans
   myConn.Close 
End Sub

Notes

If you use the adLockBatchOptimistic setting on the record set, the myRS.Update method does not make any changes to the database itself. Instead, it updates a local copy of the Recordset.

The myRS.UpdateBatch method makes the update to the database server but does not commit it, because it is inside a transaction. If an UpdateBatch method is invoked outside a transaction, the change is committed.

The myConn.CommitTrans method commits the changes. The Recordset object has been closed by this time, so there is no issue of whether the local copy of the data is changed or not.