In my last TechTip ("TechTip: Automatically Load Data into Excel"), I showed a simple example of accessing iSeries data using an SQL SELECT statement in conjunction with ADO and ODBC. That's a great process, but as the SQL statements become more complex, that simple format becomes a liability. Prepared statements offer a way around the hassles of writing those complex statements, and they have some performance benefits as well.
Every SQL statement must be interpreted by the SQL engine, which then forms a "plan" as to how that statement will be executed. This includes deciding what indexes to use and how exactly to perform the statement. Normally, this plan is re-created each time the statement is run. It adds a little overhead to the process, but it guarantees that the plan being used is as up-to-date as possible. However, if this statement runs many times, and especially if it runs thousands of times, the overhead involved in re-creating the plan becomes significant. A statement can be prepared once, creating a reusable plan. All subsequent executions of that same prepared statement use the same plan, saving significant time in high-volume applications.
This following example is written using VBA within Excel. Notice that the command object (Cmd) has its prepared property set to true. This enables parameters to be defined. The SELECT statement includes a question mark (?) where a value will be inserted later. The variable w1 contains the value OH and is loaded into the parameter Prm1. This parameter is appended to the list of parameters for the command. Additional parameters can be defined as needed and should be supplied in the same order in which they are used in the SQL statement. Once the statement is defined, it is executed much like any other SQL statement. Here's the complete code for the Excel spreadsheet:
Dim Con As New ADODB.Connection
Dim Cmd As New ADODB.Command
Dim Rs As ADODB.Recordset
Dim Prm1 As ADODB.Parameter
Dim rowCount As Integer
Dim colCount As Integer
Dim text As String
Dim val As Variant
Con.Open "PROVIDER=IBMDA400;Data Source=xxxx.xxxx.xxxx.xxxx; _
USER ID=user-id;PASSWORD=password;"
Set Cmd.ActiveConnection = Con
Cmd.CommandText = "SELECT * FROM your-lib.your-file WHERE your-field = ?"
Cmd.Prepared = True
w1 = "OH"
Set Prm1 = Cmd.CreateParameter("Parm1", adChar, adParamInputOutput, 2, w1)
Cmd.Parameters.Append Prm1
Set Rs = Nothing
Set Rs = Cmd.Execute()
Worksheets("sheet1").Activate
Range("A1").Activate
Selection.CurrentRegion.Select
Selection.ClearContents
Range("A1").Select
rowCount = 1
For colCount = 0 To Rs.Fields.Count - 1
Worksheets("Sheet1").Cells(rowCount, colCount + 1).Value = Rs.Fields(colCount).Name
Next colCount
While Not Rs.EOF
rowCount = rowCount + 1
For colCount = 0 To Rs.Fields.Count - 1
If Rs.Fields(colCount).ActualSize = -1 Then
text = ""
Else
val = Rs.Fields(colCount).Value
If VarType(val) = vbNull Then
text = ""
Else
text = val
End If
End If
Worksheets("Sheet1").Cells(rowCount, colCount + 1).Value = text
Next colCount
Rs.MoveNext
Wend
Set Rs = Nothing
Con.Close
End Sub
You'll have to change the IP address, user ID, password, library name, file name, and field names to fit your own applications.
The methods used here will work with any SQL statement. Other statements--such as insert and update--are great candidates for using prepared statements and parameter markers. If you use parameters on a call to a stored procedure, you can even retrieve the returned values of the parameters, but let's save that for another tip.
Kevin Forsythe has over 18 years of experience working with the iSeries platform and its predecessors. He has been a member of the DMC team for the past nine years. Kevin's primary responsibility is providing iSeries education, but he also provides customers with project management, system design, analysis, and technical construction. In addition to his technical skills (RPG IV, CL, OS/400, SQL, FTP, Query, VB, Net.Data), Kevin possesses the ability to communicate new and complex concepts to his students. He has been the primary instructor for DMC's iSeries-based AS/Credentials training courses since 1997 and has authored courses such as Advanced ILE, SQL, Embedded SQL, Operations Navigator, and Intro to WebSphere Studio. An award-winning speaker, he has spoken at every COMMON Conference since the spring of 2000.
LATEST COMMENTS
MC Press Online