Visual Basic is able to call external functions that are found in DLLs. Since all ODBC drivers are DLLs, Visual Basic can be used to code directly to the ODBC APIs. By coding directly to the ODBC APIs a Visual Basic application can call an iSeries™ server stored procedure and return result values.
See Code directly to ODBC APIs for more information. See Examples: RPG - Host code for ODBC stored procedures for the source code for the stored procedure.
' This statement will drop an existing stored procedure szDropProc = "drop procedure apilib.partqry2" '* This statement is used to create a stored procedure '* Unless the '* procedure is destroyed, this statement need never be re-created szCreateProc = "CREATE PROCEDURE APILIB.PARTQRY2 (INOUT P1 INTEGER," szCreateProc = szCreateProc & "INOUT P2 INTEGER)" szCreateProc = szCreateProc & "EXTERNAL NAME APILIB.SPROC2 LANGUAGE RPG GENERAL" '* Allocate statement handle rc = SQLAllocHandle(SQL_HANDLE_STMT, ghDbc, hStmt) If rc <> SQL_SUCCESS Then Call DisplayError(rc, "SQLAllocStmt failed.") Call DspSQLError(henv, SQL_NULL_HDBC, SQL_NULL_HSTMT) End If '* Drop the old Procedure rc = SQLExecDirect(hstmt, szDropProc, SQL_NTS) ' Create the new Procedure rc = SQLExecDirect(hstmt, szCreateProc, SQL_NTS) If rc <> SQL_SUCCESS And rc <> SQL_SUCCESS_WITH_INFO Then Call DisplayError(rc, "SQLCreate failed.") Call DspSQLError(henv, hdbc, hstmt) End If
'* This statement will be used to call the stored procedure szStoredProc = "call partqry2(?, ?)" '* Prepare the stored procedure call statement rc = SQLPrepare(hstmt, szStoredProc, Len(szStoredProc)) If rc <> SQL_SUCCESS And rc <> SQL_SUCCESS_WITH_INFO Then Call DisplayError(rc, "SQLPrepare failed.") Call DspSQLError(henv, hdbc, hstmt) End If
'Bind the parameters for the stored procedure rc = SQLBindParameter(hstmt, 1, SQL_PARAM_INPUT, SQL_C_LONG, _ SQL_INTEGER, lLen1, 0, sFlag, lLen1, lCbValue) If rc <> SQL_SUCCESS Then Call DisplayError(rc, "Problem binding parameter ") End If rc = SQLBindParameter(hstmt, 2, SQL_PARAM_INPUT, SQL_C_SLONG, _ SQL_INTEGER, 4, 0, lPartNumber, lLen2, lCbValue) If rc <> SQL_SUCCESS Then Call DisplayError(rc, "Problem binding parameter ") End If
rc = SQLExecute(hstmt) If lRc <> SQL_SUCCESS Then ' Free the statement handle for repeated processing rc = SQLFreeHandle( Call DspSQLError(henv, hdbc, hstmt) End If rc = SQLFetch(hstmt) If rc = SQL_NO_DATA_FOUND Then mnuClear_Click 'Clear screen txtPartNumber = lPartNumber 'Show the part number not found Call DisplayMessage("RECORD NOT FOUND") . . Else 'Get Description rc = SQLGetData(hstmt, 2, SQL_C_CHAR, sSDescription, _ 25, lcbBuffer) 'Get Quantity. SQLGetLongData uses alias SQLGetData rc = SQLGetLongData(hstmt, 3, SQL_C_SLONG, lSQuantity, _ Len(lSQuantity), lcbBuffer) 'Get Price. SQLGetDoubleData uses alias SQLGetData rc = SQLGetDoubleData(hstmt, 4, SQL_C_DOUBLE, dSPrice, _ Len(dSPrice), lcbBuffer) 'Get Received date rc = SQLGetData(hstmt, 5, SQL_C_CHAR, sSReceivedDate, _ 10, lcbBuffer) txtDescription = sSDescription 'Show description txtQuantity = lSQuantity 'Show quantity txtPrice = Format(dSPrice, "currency") 'Convert dSPrice to txtReceivedDate = CDate(sSReceivedDate) 'Convert string to d Call DisplayMessage("Record found") End If