| INFO: Visual Basic Accessing an Oracle Database Using ADOID: Q176936 
 | 
With Visual Basic and ADO, you have the ability to connect to an Oracle database through a DSN-Less connection, execute a stored procedure using parameters, and get return values from that stored procedure. The example in this article illustrates all of this functionality.
To run the sample code in this article, you may need to download and
install the Microsoft Data Access Components if you are using Visual Basic 5.0. For instructions on where to get MDAC and how to install it, please see the following article in the Microsoft Knowledge Base:
Q175018 HOWTO: Acquire and Install the Microsoft Oracle ODBC Driver
Q167225 HOWTO: Access an Oracle Database Using RDOHere are the data definition language (DDL) scripts to create these objects:
      CREATE TABLE adooracle (
            item_number    NUMBER(3) PRIMARY KEY,
            depot_number   NUMBER(3)); 
      CREATE OR REPLACE PROCEDURE adoinsert (
            insnum IN NUMBER, outnum OUT NUMBER)
      IS
      BEGIN
        INSERT INTO adooracle
          (Item_Number, Depot_Number)
        VALUES
          (insnum, 16);
        outnum := insnum/2;
      END;
 
   Control      Name      Text/Caption
   Button      cmdCheck    Check
   Button      cmdSend     Send
   Text Box    txtInput
   Label       lblInput    Input:
 
    Option Explicit
    Dim Cn As ADODB.Connection
    Dim CPw1 As ADODB.Command
    Dim CPw2 As ADODB.Command
    Dim Rs As ADODB.Recordset
    Dim Conn As String
    Dim QSQL As String
    Private Sub cmdCheck_Click()
      CPw1(0) = Val(txtInput.Text)
      Set Rs = New ADODB.Recordset
      Rs.CursorType = adOpenStatic
      Rs.LockType = adLockReadOnly
      Set Rs = CPw1.Execute
      MsgBox "Item_Number = " & Rs(0) & ".  Depot_Number = " & Rs(1) & "."
      Rs.Close
    End Sub
    Private Sub cmdSend_Click()
       CPw2(0) = Val(txtInput.Text)
       CPw2.Execute
       MsgBox "Return value from stored procedure is " & CPw2(1) & "."
    End Sub
    Private Sub Form_Load()
       'You will need to replace the "*" with the appropriate values.
       Conn = "UID=*****;PWD=****;DRIVER={Microsoft ODBC for Oracle};" _
            & "SERVER=*****;"
       Set Cn = New ADODB.Connection
       With Cn
         .ConnectionString = Conn
         .CursorLocation = adUseClient
         .Open
       End With
       QSQL = "Select Item_Number, Depot_Number From adooracle Where " _
       & "item_number = ?"
       Set CPw1 = New ADODB.Command
       With CPw1
         .ActiveConnection = Cn
         .CommandText = QSQL
         .CommandType = adCmdText
         .Parameters.Append .CreateParameter(, adInteger, adParamInput)
       End With
       QSQL = "adoinsert"
       Set CPw2 = New ADODB.Command
       With CPw2
         .ActiveConnection = Cn
         .CommandText = QSQL
         .CommandType = adCmdStoredProc
         .Parameters.Append .CreateParameter(, adInteger, adParamInput)
         .Parameters.Append .CreateParameter(, adDouble, adParamOutput)
       End With
    End Sub
    Private Sub Form_Unload(Cancel As Integer)
       Cn.Close
       Set Cn = Nothing
       Set CPw1 = Nothing
       Set CPw2 = Nothing
    End Sub
 
Conn = "UID=<uid>;PWD=<pwd>;DRIVER={Microsoft ODBC for Oracle};" _
           & "SERVER=<MyServer>;"
   Set Cn = New ADODB.Connection
   With Cn
       .ConnectionString = Conn
       .CursorLocation = adUseClient
       .Open
   End With
 
Conn = "UID=<uid>;PWD=<pwd>;DRIVER={Microsoft ODBC for Oracle};" _
           & "SERVER==<MyServer>;"
 
QSQL = "Select Item_Number, Depot_Number From adooracle Where " _
   & "item_number = ?"
   Set CPw1 = New ADODB.Command
   With CPw1
       .ActiveConnection = Cn
       .CommandText = QSQL
       .CommandType = adCmdText
       .Parameters.Append .CreateParameter(, adInteger, adParamInput)
   End With
   QSQL = "adoinsert"
   Set CPw2 = New ADODB.Command
   With CPw2
       .ActiveConnection = Cn
       .CommandText = QSQL
       .CommandType = adCmdStoredProc
       .Parameters.Append .CreateParameter(, adInteger, adParamInput)
       .Parameters.Append .CreateParameter(, adDouble, adParamOutput)
   End With
 "Use the CommandType property to optimize evaluation of the CommandText property. If the CommandType property value equals adCmdUnknown (the default value), you may experience diminished performance because ADO must make calls to the provider to determine if the CommandText property is an SQL statement, a stored procedure, or a table name. If you know what type of command you're using, setting the CommandType property instructs ADO to go directly to the relevant code. If the CommandType property does not match the type of command in the CommandText property, an error occurs when you call the Execute method."
"If you specify a variable-length data type in the Type argument, you must either pass a Size argument or set the Size property of the Parameter object before appending it to the Parameters collection; otherwise, an error occurs."
For more information on these issues, please consult your Oracle SQL*Net
2.3 documentation, the Help file for the Microsoft ODBC Driver for Oracle,
the ADO HTML that comes with MDAC 1.5, Books Online that comes with Visual Basic 6.0 or your Oracle 7 server documentation.
Microsoft ODBC Driver for Oracle Help File
ADO Help HTML
"Oracle PL/SQL Programming" by Steven Feuerstein
"Hitchhiker's Guide to Visual Basic & SQL Server" by William Vaughn, Fifth
Edition
For additional information, please see the following article in the
Microsoft Knowledge Base:
Q174679 HOWTO: Retrieve Resultsets from Oracle Stored Procedures
Q175018 HOWTO: Acquire and Install the Microsoft Oracle ODBC
Q174981 HOWTO: Retrieve Typical Resultsets from Oracle Stored Procedures
Q167225 HOWTO: Access an Oracle Database Using RDO
Q176086 HOWTO: Retrieve Recordsets from Oracle Stored Procs Using ADO
Additional query words: oracle stored procedures ado kbdse
Keywords          : kbADO150 kbADO200 kbDatabase kbOracle kbVBp500 kbVBp600 
Version           : WINDOWS:5.0,6.0
Platform          : WINDOWS 
Issue type        : kbinfo Last Reviewed: March 9, 1999