MDAC 2.5 SDK - ADO


 

ActiveConnection, CommandText, CommandTimeout, CommandType, Size, and Direction Properties Example (VB)

See Also

This example uses the ActiveConnection, CommandText, CommandTimeout, CommandType, Size, and Direction properties to execute a stored procedure.

Public Sub ActiveConnectionX()

   Dim cnn1 As ADODB.Connection
   Dim cmdByRoyalty As ADODB.Command
   Dim prmByRoyalty As ADODB.Parameter
   Dim rstByRoyalty As ADODB.Recordset
   Dim rstAuthors As ADODB.Recordset
   Dim intRoyalty As Integer
   Dim strAuthorID As String
   Dim strCnn As String

   ' Define a command object for a stored procedure.
   Set cnn1 = New ADODB.Connection
   strCnn = "Provider=sqloledb;" & _
      "Data Source=srv;Initial Catalog=Pubs;User Id=sa;Password=; "
   cnn1.Open strCnn
   Set cmdByRoyalty = New ADODB.Command
   Set cmdByRoyalty.ActiveConnection = cnn1
   cmdByRoyalty.CommandText = "byroyalty"
   cmdByRoyalty.CommandType = adCmdStoredProc
   cmdByRoyalty.CommandTimeout = 15
      
   ' Define the stored procedure's input parameter.
   intRoyalty = Trim(InputBox( _
      "Enter royalty:"))
   Set prmByRoyalty = New ADODB.Parameter
   prmByRoyalty.Type = adInteger
   prmByRoyalty.Size = 3
   prmByRoyalty.Direction = adParamInput
   prmByRoyalty.Value = intRoyalty
   cmdByRoyalty.Parameters.Append prmByRoyalty
  
   ' Create a recordset by executing the command.
   Set rstByRoyalty = cmdByRoyalty.Execute()
      
   ' Open the Authors table to get author names for display.
   Set rstAuthors = New ADODB.Recordset
   rstAuthors.Open "Authors", strCnn, , , adCmdTable
   
   ' Print current data in the recordset, adding
   ' author names from Authors table.
   Debug.Print "Authors with " & intRoyalty & _
      " percent royalty"
   Do While Not rstByRoyalty.EOF
      strAuthorID = rstByRoyalty!au_id
      Debug.Print , rstByRoyalty!au_id & ", ";
      rstAuthors.Filter = "au_id = '" & strAuthorID & "'"
      Debug.Print rstAuthors!au_fname & " " & _
         rstAuthors!au_lname
      rstByRoyalty.MoveNext
   Loop

   rstByRoyalty.Close
   rstAuthors.Close
   cnn1.Close
   
End Sub