Preparing a Query Statement String with Parameters (Embedded SQL Guide)
Go Up to Method 4: Query Statements with Parameters (Embedded SQL Guide)
After an input and an output XSQLDA are created for holding parameters of a statement string, and the select-list items returned when the statement is executed, the statement string can be created and prepared. When a statement string is prepared, InterBase replaces the placeholder parameters in the string with information about the actual parameters used. The information about the parameters must be assigned to the input XSQLDA (and perhaps adjusted) before the statement can be executed. When the statement string is executed, InterBase stores select-list items in the output XSQLDA.
To prepare a query statement string with parameters, follow these steps:
- 1. Elicit a statement string from the user or create one that contains the SQL statement to be processed. For example, the following statement creates a SQL statement string with placeholder parameters:
char *str = "SELECT * FROM DEPARTMENT WHERE BUDGET = ?, LOCATION = ?";
- This statement string contains two parameters: a value to be assigned to the
BUDGETfield and a value to be assigned to theLOCATIONfield. - 2. Prepare and name the statement string with
PREPARE. The name is used in subsequent calls toDESCRIBEandEXECUTE:
EXEC SQL PREPARE SQL_STMT FROM :str;
SQL_STMTis the name assigned to the prepared statement string.- 3. Use
DESCRIBE INPUTto fill the inputXSQLDAwith information about the parameters contained in the SQL statement:
EXEC SQL DESCRIBE INPUT SQL_STMT USING SQL DESCRIPTOR in_sqlda;
- 4. Compare the
sqlnfield of theXSQLDAto thesqldfield to determine if the input descriptor can accommodate the number of parameters contained in the statement. If not, free the storage previously allocated to the input descriptor, reallocate storage to reflect the number of parameters specified bysqld, resetsqlnandversion, then executeDESCRIBE INPUTagain:
if (in_sqlda->sqld > in_sqlda->sqln)
{
n = in_sqlda->sqld;
free(in_sqlda);
in_sqlda = (XSQLDA *)malloc(XSQLDA_LENGTH(n));
in_sqlda->sqln = n;
in_sqlda->version = SQLDA_CURRENT_VERSION;
EXEC SQL
DESCRIBE INPUT SQL_STMT USING SQL DESCRIPTOR in_sqlda;
}
- 5. Process each
XSQLVARparameter structure in the inputXSQLDA. Processing a parameter structure involves up to four steps:- Coercing a data type of a parameter (optional).
- Allocating local storage for the data pointed to by the
sqldatafield of theXSQLVAR. This step is only required if space for local variables is not allocated until run time. The following example illustrates dynamic allocation of local variable storage space. - Providing a value for the parameter consistent with its data type (required).
- Providing a NULL value indicator for the parameter.
- These steps must be followed in the order presented. The following code example illustrates these steps, looping through each
XSQLVARstructure in thein_sqldaXSQLDA:
for (i=0, var = in_sqlda->sqlvar; i < in_sqlda->sqld; i++, var++)
{
/* Process each XSQLVAR parameter structure here.
The parameter structure is pointed to by var.*/
dtype = (var->sqltype & ~1) /* drop flag bit for now */
switch (dtype)
{
case SQL_VARYING: /* coerce to SQL_TEXT */
var->sqltype = SQL_TEXT;
/* allocate proper storage */
var->sqldata = (char *)malloc(sizeof(char)*var->sqllen);
/* provide a value for the parameter. See case SQL_LONG */
. . .
break;
case SQL_TEXT:
var->sqldata = (char *)malloc(sizeof(char)*var->sqllen);
/* provide a value for the parameter. See case SQL_LONG */
. . .
break;
case SQL_LONG:
var->sqldata = (char *)malloc(sizeof(long));
/* provide a value for the parameter */
*(long *)(var->sqldata) = 17;
break;
. . .
} /* end of switch statement */
if (sqltype & 1)
{
/* allocate variable to hold NULL status */
var->sqlind = (short *)malloc(sizeof(short));
}
} /* end of for loop */
- For more information about data type coercion and NULL indicators, see Coercing Data Types.
- 6. Use
DESCRIBE OUTPUTto fill the outputXSQLDAwith information about the select-list items returned by the statement:
EXEC SQL DESCRIBE OUTPUT SQL_STMT INTO SQL DESCRIPTOR out_sqlda;
- 7. Compare the
sqlnfield of theXSQLDAto thesqldfield to determine if the output descriptor can accommodate the number of select-list items specified in the statement. If not, free the storage previously allocated to the output descriptor, reallocate storage to reflect the number of select-list items specified bysqld, resetsqlnandversion, and executeDESCRIBE OUTPUTagain:
if (out_sqlda->sqld > out_sqlda->sqln)
{
n = out_sqlda->sqld;
free(out_sqlda);
out_sqlda = (XSQLDA *)malloc(XSQLDA_LENGTH(n));
out_sqlda->sqln = n;
out_sqlda->version = SQLDA_CURRENT_VERSION;
EXEC SQL
DESCRIBE OUTPUT SQL_STMT INTO SQL DESCRIPTOR out_sqlda;
}
- 8. Set up an
XSQLVARstructure for each item returned. Setting up an item structure involves the following steps:- Coercing a data type of an item (optional).
- Allocating local storage for the data pointed to by the
sqldatafield of theXSQLVAR. This step is only required if space for local variables is not allocated until run time. The following example illustrates dynamic allocation of local variable storage space. - Providing a
NULLvalue indicator for the parameter (optional).
- The following code example illustrates these steps, looping through each
XSQLVARstructure in theout_sqldaXSQLDA:
for (i=0, var = out_sqlda->sqlvar; i < out_sqlda->sqld; i++, var++)
{
dtype = (var->sqltype & ~1) /* drop flag bit for now */
switch (dtype)
{
case SQL_VARYING:
var->sqltype = SQL_TEXT;
break;
case SQL_TEXT:
var->sqldata = (char *)malloc(sizeof(char)*var->sqllen);
break;
case SQL_LONG:
var->sqldata = (char *)malloc(sizeof(long));
break;
/* process remaining types */
} /* end of switch statements */
if (sqltype & 1)
{
/* allocate variable to hold NULL status */
var->sqlind = (short *)malloc(sizeof(short));
}
} /* end of for loop */
- For more information about data type coercion and NULL indicators, see Coercing Data Types.