25.2.6. C API Prepared Statement Function Overview
The functions available for prepared statement processing are
summarized here and described in greater detail in a later
section. See
Section 25.2.7, “C API Prepared Statement Function Descriptions”.
Call mysql_stmt_init()
to create a statement
handle, then mysql_stmt_prepare
to prepare
it, mysql_stmt_bind_param()
to supply the
parameter data, and mysql_stmt_execute()
to
execute the statement. You can repeat the
mysql_stmt_execute()
by changing parameter
values in the respective buffers supplied through
mysql_stmt_bind_param()
.
If the statement is a SELECT
or any other
statement that produces a result set,
mysql_stmt_prepare()
also returns the result
set metadata information in the form of a
MYSQL_RES
result set through
mysql_stmt_result_metadata()
.
You can supply the result buffers using
mysql_stmt_bind_result()
, so that the
mysql_stmt_fetch()
automatically returns data
to these buffers. This is row-by-row fetching.
You can also send the text or binary data in chunks to server
using mysql_stmt_send_long_data()
. See
Section 25.2.7.25, “mysql_stmt_send_long_data()
”.
When statement execution has been completed, the statement
handle must be closed using
mysql_stmt_close()
so that all resources
associated with it can be freed.
If you obtained a SELECT
statement's result
set metadata by calling
mysql_stmt_result_metadata()
, you should also
free the metadata using mysql_free_result()
.
Execution Steps
To prepare and execute a statement, an application follows these
steps:
Create a prepared statement handle with
msyql_stmt_init()
. To prepare the
statement on the server, call
mysql_stmt_prepare()
and pass it a string
containing the SQL statement.
If the statement produces a result set, call
mysql_stmt_result_metadata()
to obtain
the result set metadata. This metadata is itself in the form
of result set, albeit a separate one from the one that
contains the rows returned by the query. The metadata result
set indicates how many columns are in the result and
contains information about each column.
Set the values of any parameters using
mysql_stmt_bind_param()
. All parameters
must be set. Otherwise, statement execution returns an error
or produces unexpected results.
Call mysql_stmt_execute()
to execute the
statement.
If the statement produces a result set, bind the data
buffers to use for retrieving the row values by calling
mysql_stmt_bind_result()
.
Fetch the data into the buffers row by row by calling
mysql_stmt_fetch()
repeatedly until no
more rows are found.
Repeat steps 3 through 6 as necessary, by changing the
parameter values and re-executing the statement.
When mysql_stmt_prepare()
is called, the
MySQL client/server protocol performs these actions:
The server parses the statement and sends the okay status
back to the client by assigning a statement ID. It also
sends total number of parameters, a column count, and its
metadata if it is a result set oriented statement. All
syntax and semantics of the statement are checked by the
server during this call.
The client uses this statement ID for the further
operations, so that the server can identify the statement
from among its pool of statements.
When mysql_stmt_execute()
is called, the
MySQL client/server protocol performs these actions:
The client uses the statement handle and sends the parameter
data to the server.
The server identifies the statement using the ID provided by
the client, replaces the parameter markers with the newly
supplied data, and executes the statement. If the statement
produces a result set, the server sends the data back to the
client. Otherwise, it sends an okay status and total number
of rows changed, deleted, or inserted.
When mysql_stmt_fetch()
is called, the MySQL
client/server protocol performs these actions:
If an error occurs, you can get the statement error code, error
message, and SQLSTATE value using
mysql_stmt_errno()
,
mysql_stmt_error()
, and
mysql_stmt_sqlstate()
, respectively.
Prepared Statement Logging
For prepared statements that are executed with the
mysql_stmt_prepare()
and
mysql_stmt_execute()
C API functions, the
server writes Prepare
and
Execute
lines to the general query log so
that you can tell when statements are prepared and executed.
Suppose that you prepare and execute a statement as follows:
Call mysql_stmt_prepare()
to prepare the
statement string "SELECT ?"
.
Call mysql_stmt_bind_param()
to bind the
value 3
to the parameter in the prepared
statement.
Call mysql_stmt_execute()
to execute the
prepared statement.
As a result of the preceding calls, the server writes the
following lines to the general query log:
Prepare [1] SELECT ?
Execute [1] SELECT 3
Each Prepare
and Execute
line in the log is tagged with a
[N
]
statement
identifier so that you can keep track of which prepared
statement is being logged. N
is a
positive integer. If there are multiple prepared statements
active simultaneously for the client,
N
may be greater than 1. Each
Execute
lines shows a prepared statement
after substitution of data values for ?
parameters.
Version notes: Prepare
lines are displayed
without [N
]
before
MySQL 4.1.10. Execute
lines are not displayed
at all before MySQL 4.1.10.