204 lines
11 KiB
HTML
204 lines
11 KiB
HTML
<?xml version="1.0" encoding="UTF-8"?>
|
|
<!DOCTYPE html
|
|
PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd">
|
|
<html lang="en-us" xml:lang="en-us">
|
|
<head>
|
|
<meta http-equiv="Content-Type" content="text/html; charset=utf-8" />
|
|
<meta name="security" content="public" />
|
|
<meta name="Robots" content="index,follow" />
|
|
<meta http-equiv="PICS-Label" content='(PICS-1.1 "http://www.icra.org/ratingsv02.html" l gen true r (cz 1 lz 1 nz 1 oz 1 vz 1) "http://www.rsac.org/ratingsv01.html" l gen true r (n 0 s 0 v 0 l 0) "http://www.classify.org/safesurf/" l gen true r (SS~~000 1))' />
|
|
<meta name="DC.Type" content="reference" />
|
|
<meta name="DC.Title" content="Execute prepared statements" />
|
|
<meta name="abstract" content="If an SQL statement is used more than once, it is best to have the statement prepared and then executed." />
|
|
<meta name="description" content="If an SQL statement is used more than once, it is best to have the statement prepared and then executed." />
|
|
<meta name="DC.Relation" scheme="URI" content="rzaikodbcapiinfo.htm" />
|
|
<meta name="DC.Relation" scheme="URI" content="string2byte.htm" />
|
|
<meta name="copyright" content="(C) Copyright IBM Corporation 1999, 2006" />
|
|
<meta name="DC.Rights.Owner" content="(C) Copyright IBM Corporation 1999, 2006" />
|
|
<meta name="DC.Format" content="XHTML" />
|
|
<meta name="DC.Identifier" content="executeprepstmt" />
|
|
<meta name="DC.Language" content="en-us" />
|
|
<!-- All rights reserved. Licensed Materials Property of IBM -->
|
|
<!-- US Government Users Restricted Rights -->
|
|
<!-- Use, duplication or disclosure restricted by -->
|
|
<!-- GSA ADP Schedule Contract with IBM Corp. -->
|
|
<link rel="stylesheet" type="text/css" href="./ibmdita.css" />
|
|
<link rel="stylesheet" type="text/css" href="./ic.css" />
|
|
<title>Execute prepared statements</title>
|
|
</head>
|
|
<body id="executeprepstmt"><a name="executeprepstmt"><!-- --></a>
|
|
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
|
|
<h1 class="topictitle1">Execute prepared statements</h1>
|
|
<div><p>If an <span class="keyword">SQL</span> statement
|
|
is used more than once, it is best to have the statement prepared and then
|
|
executed.</p>
|
|
<div class="section"><p>When a statement is prepared, variable information can be passed
|
|
as parameter markers, which are denoted by question marks (?). When the statement
|
|
is executed, the parameter markers are replaced with the real variable information.</p>
|
|
</div>
|
|
<div class="section"><p>Preparing the statement is performed at the server. The <span class="keyword">SQL</span> statements are compiled and
|
|
the access plans are built. This allows the statements to be executed much
|
|
more efficiently. When compared to using dynamic <span class="keyword">SQL</span> to
|
|
execute the statements, the result is much closer to static <span class="keyword">SQL</span>.
|
|
Extened Dynamic preserves prepared statements accross job sessions. This allows
|
|
prepared statements with parameter markers to be executed multiple times within
|
|
the job session even without Extended Dynamic ON. When the database server
|
|
prepares the statements, it saves some of them in a special iSeries™ object
|
|
called a package (*SQLPKG). This approach is called <strong>Extended Dynamic <span class="keyword">SQL</span></strong>. Packages are created
|
|
automatically by the driver; an option is provided to turn off Package Support.
|
|
This is covered in <a href="rzaikodbcperfarch.htm#odbcperfarch">The performance architecture of the iSeries Access for Windows ODBC driver</a>.
|
|
</p>
|
|
</div>
|
|
<div class="section"><h4 class="sectiontitle">SQLPrepare</h4><p>Prepares an <span class="keyword">SQL</span> statement
|
|
for execution: </p>
|
|
<p>In C, this statement is coded: </p>
|
|
<pre>SQLCHAR szSQLstr[ ] = "INSERT INTO NAMEID VALUES (?,?)";
|
|
|
|
rc = SQLPrepare(hstmt, szSQLstr, SQL_NTS);</pre>
|
|
<div class="note"><span class="notetitle">Note:</span> SQL_NTS indicates
|
|
that the string is null-terminated.</div>
|
|
</div>
|
|
<div class="section"><h4 class="sectiontitle">SQLBindParameter</h4><p>Allows application to specify storage,
|
|
data type, and length associated with a parameter marker in an <span class="keyword">SQL</span> statement.</p>
|
|
<p>In
|
|
the example, parameter 1 is found in a signed double word field called <strong>id</strong>.
|
|
Parameter 2 is found in an unsigned character array called <strong>name</strong>. Since
|
|
the last parameter is null, the driver expects that <strong>name</strong> is null-terminated
|
|
as it will calculate the string's length.</p>
|
|
<p> In C, this statement is coded: </p>
|
|
<pre>
|
|
SQLCHAR szName[51];
|
|
SQLINTEGER id, parmLength = 50, lenParm1 = sizeof(SQLINTEGER) , lenParm2 = SQL_NTS ;
|
|
|
|
rc = SQLBindParameter(hstmt, 1, SQL_PARAM_INPUT, SQL_C_LONG, SQL_INTEGER,
|
|
sizeof(SQLINTEGER), 0, &id, sizeof(SQLINTEGER), &lenParm1);
|
|
rc = SQLBindParameter(hstmt, 2, SQL_PARAM_INPUT, SQL_C_CHAR, SQL_VARCHAR,
|
|
parmLength, 0, szName, sizeof(szName), &lenParm2);</pre>
|
|
</div>
|
|
<div class="section"><h4 class="sectiontitle">SQLExecute</h4><p>Executes a prepared statement, using
|
|
current values of parameter markers: </p>
|
|
<p>In C, this statement is coded: </p>
|
|
<pre>id=500;
|
|
strcpy(szName, "TEST");
|
|
rc = SQLExecute(hstmt); // Insert a record with id = 500, name = "TEST"
|
|
id=600;
|
|
strcpy(szName, "ABCD");
|
|
rc = SQLExecute(hstmt); // Insert a record with id = 600, name = "ABCD"</pre>
|
|
</div>
|
|
<div class="section"><h4 class="sectiontitle">SQLParamData / SQLPutData</h4><p>Visual Basic does not
|
|
directly support pointers or fixed-location ANSI character null-terminated
|
|
strings. For this reason, it is best to use another method to bind Character
|
|
and Binary parameters. One method is to convert Visual Basic String data types
|
|
to/from an array of Byte data types and bind the array of Byte. This method
|
|
is demonstrated in <a href="string2byte.htm#string2byte">Convert strings and arrays of byte</a>. </p>
|
|
<p>Another
|
|
method, that should only be used for input parameters, is to supply the parameters
|
|
at processing time. This is done using <strong>SQLParamData</strong> and <strong>SQLPutData</strong> APIs: </p>
|
|
<ul><li>They work together to supply parameters.</li>
|
|
<li><strong>SQLParamData</strong> moves the pointer to the next parameter.</li>
|
|
<li><strong>SQLPutData</strong> then supplies the data for that parameter. </li>
|
|
</ul>
|
|
<pre>'s_parm is a character buffer to hold the parameters
|
|
's_parm(1) contains the first parameter
|
|
Static s_parm(2) As String
|
|
s_parm(1) = "Rear Bumper"
|
|
s_parm(2) = "ABC Auto Part Store"
|
|
Dim rc As Integer
|
|
Dim cbValue As Long
|
|
Dim s_insert As String
|
|
Dim hStmt As Long
|
|
Dim lPartID As Long
|
|
|
|
rc = SQLAllocHandle(SQL_HANDLE_STMT, ghDbc, hStmt)
|
|
If rc <> SQL_SUCCESS Then _
|
|
Call DspSQLDiagRec(SQL_HANDLE_DBC, ghDbc, "SQLAllocStmt failed.")
|
|
|
|
s_insert = "INSERT INTO ODBCSAMPLE VALUES(?, ?, ?)"
|
|
|
|
rc = SQLBindParameter(hStmt, 1, SQL_PARAM_INPUT, SQL_C_LONG, SQL_INTEGER, _
|
|
4, 0, lPartID, 4, ByVal 0)
|
|
If rc <> SQL_SUCCESS Then _
|
|
Call DspSQLDiagRec(SQL_HANDLE_DBC, ghDbc, "SQLBindParameter failed.")
|
|
|
|
'#define SQL_LEN_DATA_AT_EXEC_OFFSET (-100) the parms will be supplied at run time
|
|
cbValue = -100
|
|
|
|
' Caller set 8th parameter to "ByVal 2" so driver will return
|
|
' 2 in the token when caller calls SQLParamData
|
|
rc = SQLBindParameter(hStmt, 2, SQL_PARAM_INPUT, SQL_C_CHAR, SQL_CHAR, _
|
|
4, 0, ByVal 2, 0, cbValue)
|
|
If rc <> SQL_SUCCESS Then _
|
|
Call DspSQLDiagRec(SQL_HANDLE_DBC, ghDbc, "SQLBindParameter failed.")
|
|
|
|
' Caller set 8th parameter to "ByVal 3" so driver will return
|
|
' 3 in the token when caller calls SQLParamData the second time.
|
|
rc = SQLBindParameter(hStmt, 3, SQL_PARAM_INPUT, SQL_C_CHAR, SQL_CHAR, _
|
|
4, 0, ByVal 3, 0, cbValue)
|
|
If rc <> SQL_SUCCESS Then _
|
|
Call DspSQLDiagRec(SQL_HANDLE_DBC, ghDbc, "SQLBindParameter failed.")
|
|
|
|
' Prepare the insert statement once.
|
|
rc = SQLPrepare(hStmt, s_insert, SQL_NTS)
|
|
|
|
lPartID = 1
|
|
rc = SQLExecute(hStmt) ' Execute multiple times if needed.
|
|
|
|
' Since parameters 2 and 3 are bound with cbValue set to -100,
|
|
' SQLExecute returns SQL_NEED_DATA
|
|
|
|
If rc = SQL_NEED_DATA Then
|
|
|
|
' See comment at SQLBindParameter: token receives 2.
|
|
rc = SQLParamData(hStmt, token)
|
|
|
|
If rc <> SQL_NEED_DATA Or token <> 2 Then _
|
|
Call DspSQLDiagRec(SQL_HANDLE_DBC, ghDbc, "SQLParamData failed.")
|
|
|
|
' Provide data for parameter 2.
|
|
rc = SQLPutData(hStmt, ByVal s_parm(1), Len(s_parm(1)))
|
|
If rc <> SQL_SUCCESS Then _
|
|
Call DspSQLDiagRec(SQL_HANDLE_DBC, ghDbc, "SQLPutData failed.")
|
|
|
|
' See comment at SQLBindParameter: token receives 3.
|
|
rc = SQLParamData(hStmt, token)
|
|
If rc <> SQL_NEED_DATA Or token <> 3 Then _
|
|
Call DspSQLDiagRec(SQL_HANDLE_DBC, ghDbc, "SQLParamData failed.")
|
|
|
|
' Provide data for parameter 2.
|
|
rc = SQLPutData(hStmt, ByVal s_parm(2), Len(s_parm(2)))
|
|
If rc <> SQL_SUCCESS Then _
|
|
Call DspSQLDiagRec(SQL_HANDLE_DBC, ghDbc, "SQLPutData failed.")
|
|
|
|
' Call SQLParamData one more time.
|
|
' Since all data are provided, driver will execute the request.
|
|
rc = SQLParamData(hStmt, token)
|
|
If rc <> SQL_SUCCESS Then _
|
|
Call DspSQLDiagRec(SQL_HANDLE_DBC, ghDbc, "SQLParamData failed.")
|
|
Else
|
|
Call DspSQLDiagRec(SQL_HANDLE_STMT, hStmt, "SQLExecute failed.")
|
|
End If</pre>
|
|
<div class="note"><span class="notetitle">Notes:</span> <ol><li>These two statements operate together to supply unbound parameter values
|
|
when the statement is executed.</li>
|
|
<li>Each call to <strong>SQLParamData</strong> moves the internal pointer to the next
|
|
parameter for <strong>SQLPutData</strong> to supply data to. After the last parameter
|
|
is filled, <strong>SQLParamData</strong> must be called again for the statement to be
|
|
executed.</li>
|
|
<li>If <strong>SQLPutData</strong> supplies data for parameter markers, the parameter
|
|
must be bound. Use the <strong>cbValue</strong> parameter set to a variable whose value
|
|
is SQL_DATA_AT_EXEC when the statement is executed.</li>
|
|
</ol>
|
|
</div>
|
|
</div>
|
|
</div>
|
|
<div>
|
|
<ul class="ullinks">
|
|
<li class="ulchildlink"><strong><a href="string2byte.htm">Convert strings and arrays of byte</a></strong><br />
|
|
The following Visual Basic functions can assist in converting strings and arrays of byte.</li>
|
|
</ul>
|
|
|
|
<div class="familylinks">
|
|
<div class="parentlink"><strong>Parent topic:</strong> <a href="rzaikodbcapiinfo.htm" title="Identify the files required to build an ODBC application.">Files required to build an ODBC application</a></div>
|
|
</div>
|
|
</div>
|
|
</body>
|
|
</html> |