Prepared statements use several data structures:
To obtain a statement handler, pass a
MYSQLconnection handler tomysql_stmt_init(), which returns a pointer to aMYSQL_STMTdata structure. This structure is used for further operations with the statement. To specify the statement to prepare, pass theMYSQL_STMTpointer and the statement string tomysql_stmt_prepare().-
To provide input parameters for a prepared statement, set up
MYSQL_BINDstructures and pass them tomysql_stmt_bind_param(). To receive output column values, set upMYSQL_BINDstructures and pass them tomysql_stmt_bind_result().MYSQL_BINDstructures are also used withmysql_bind_param(), which enables defining attributes that apply to the next query sent to the server. The
MYSQL_TIMEstructure is used to transfer temporal data in both directions.
The following discussion describes the prepared statement data types in detail. For examples that show how to use them, see Section 6.4.10, “mysql_stmt_execute()”, and Section 6.4.11, “mysql_stmt_fetch()”.
-
This structure is a handler for a prepared statement. A handler is created by calling
mysql_stmt_init(), which returns a pointer to aMYSQL_STMT. The handler is used for all subsequent operations with the statement until you close it withmysql_stmt_close(), at which point the handler becomes invalid and should no longer be used.The
MYSQL_STMTstructure has no members intended for application use. Applications should not try to copy aMYSQL_STMTstructure. There is no guarantee that such a copy will be usable.Multiple statement handlers can be associated with a single connection. The limit on the number of handlers depends on the available system resources.
-
This structure is used both for statement input (data values sent to the server) and output (result values returned from the server):
For input, use
MYSQL_BINDstructures withmysql_bind_param()to define attributes for a query. (In the following discussion, treat any mention of statement parameters for prepared statements as also applying to query attributes.)For output, use
MYSQL_BINDstructures withmysql_stmt_bind_result()to bind buffers to result set columns, for use in fetching rows withmysql_stmt_fetch().
To use a
MYSQL_BINDstructure, zero its contents to initialize it, then set its members appropriately. For example, to declare and initialize an array of threeMYSQL_BINDstructures, use this code:MYSQL_BIND bind[3]; memset(bind, 0, sizeof(bind));The
MYSQL_BINDstructure contains the following members for use by application programs. For several of the members, the manner of use depends on whether the structure is used for input or output.-
enum enum_field_types buffer_typeThe type of the buffer. This member indicates the data type of the C language variable bound to a statement parameter or result set column. For input,
buffer_typeindicates the type of the variable containing the value to be sent to the server. For output, it indicates the type of the variable into which a value received from the server should be stored. For permissiblebuffer_typevalues, see Section 6.2.1, “C API Prepared Statement Type Codes”. -
void *bufferA pointer to the buffer to be used for data transfer. This is the address of a C language variable.
For input,
bufferis a pointer to the variable in which you store the data value for a statement parameter. When you callmysql_stmt_execute(), MySQL use the value stored in the variable in place of the corresponding parameter marker in the statement (specified with?in the statement string).For output,
bufferis a pointer to the variable in which to return a result set column value. When you callmysql_stmt_fetch(), MySQL stores a column value from the current row of the result set in this variable. You can access the value when the call returns.To minimize the need for MySQL to perform type conversions between C language values on the client side and SQL values on the server side, use C variables that have types similar to those of the corresponding SQL values:
For numeric data types,
buffershould point to a variable of the proper numeric C type. For integer variables (which can becharfor single-byte values or an integer type for larger values), you should also indicate whether the variable has theunsignedattribute by setting theis_unsignedmember, described later.For character (nonbinary) and binary string data types,
buffershould point to a character buffer.For date and time data types,
buffershould point to aMYSQL_TIMEstructure.
For guidelines about mapping between C types and SQL types and notes about type conversions, see Section 6.2.1, “C API Prepared Statement Type Codes”, and Section 6.2.2, “C API Prepared Statement Type Conversions”.
-
unsigned long buffer_lengthThe actual size of
*bufferin bytes. This indicates the maximum amount of data that can be stored in the buffer. For character and binary C data, thebuffer_lengthvalue specifies the length of*bufferwhen used withmysql_stmt_bind_param()to specify input values, or the maximum number of output data bytes that can be fetched into the buffer when used withmysql_stmt_bind_result(). -
unsigned long *lengthA pointer to an
unsigned longvariable that indicates the actual number of bytes of data stored in*buffer.lengthis used for character or binary C data.For input parameter data binding, set
*lengthto indicate the actual length of the parameter value stored in*buffer. This is used bymysql_stmt_execute().For output value binding, MySQL sets
*lengthwhen you callmysql_stmt_fetch(). Themysql_stmt_fetch()return value determines how to interpret the length:If the return value is 0,
*lengthindicates the actual length of the parameter value.If the return value is
MYSQL_DATA_TRUNCATED,*lengthindicates the nontruncated length of the parameter value. In this case, the minimum of*lengthandbuffer_lengthindicates the actual length of the value.
lengthis ignored for numeric and temporal data types because thebuffer_typevalue determines the length of the data value.If you must determine the length of a returned value before fetching it, see Section 6.4.11, “mysql_stmt_fetch()”, for some strategies.
-
bool *is_nullThis member points to a
boolvariable that is true if a value isNULL, false if it is notNULL. For input, set*is_nullto true to indicate that you are passing aNULLvalue as a statement parameter.is_nullis a pointer to a boolean scalar, not a boolean scalar, to provide flexibility in how you specifyNULLvalues:If your data values are always
NULL, useMYSQL_TYPE_NULLas thebuffer_typevalue when you bind the column. The otherMYSQL_BINDmembers, includingis_null, do not matter.If your data values are always
NOT NULL, setis_null = (bool*) 0, and set the other members appropriately for the variable you are binding.In all other cases, set the other members appropriately and set
is_nullto the address of aboolvariable. Set that variable's value to true or false appropriately between executions to indicate whether the corresponding data value isNULLorNOT NULL, respectively.
For output, when you fetch a row, MySQL sets the value pointed to by
is_nullto true or false according to whether the result set column value returned from the statement is or is notNULL. -
bool is_unsignedThis member applies for C variables with data types that can be
unsigned(char,short int,int,long long int). Setis_unsignedto true if the variable pointed to bybufferisunsignedand false otherwise. For example, if you bind asigned charvariable tobuffer, specify a type code ofMYSQL_TYPE_TINYand setis_unsignedto false. If you bind anunsigned charinstead, the type code is the same butis_unsignedshould be true. (Forchar, it is not defined whether it is signed or unsigned, so it is best to be explicit about signedness by usingsigned charorunsigned char.)is_unsignedapplies only to the C language variable on the client side. It indicates nothing about the signedness of the corresponding SQL value on the server side. For example, if you use anintvariable to supply a value for aBIGINT UNSIGNEDcolumn,is_unsignedshould be false becauseintis a signed type. If you use anunsigned intvariable to supply a value for aBIGINTcolumn,is_unsignedshould be true becauseunsigned intis an unsigned type. MySQL performs the proper conversion between signed and unsigned values in both directions, although a warning occurs if truncation results. -
bool *errorFor output, set this member to point to a
boolvariable to have truncation information for the parameter stored there after a row fetching operation. When truncation reporting is enabled,mysql_stmt_fetch()returnsMYSQL_DATA_TRUNCATEDand*erroris true in theMYSQL_BINDstructures for parameters in which truncation occurred. Truncation indicates loss of sign or significant digits, or that a string was too long to fit in a column. Truncation reporting is enabled by default, but can be controlled by callingmysql_options()with theMYSQL_REPORT_DATA_TRUNCATIONoption.
-
This structure is used to send and receive
DATE,TIME,DATETIME, andTIMESTAMPdata directly to and from the server. Set thebuffermember to point to aMYSQL_TIMEstructure, and set thebuffer_typemember of aMYSQL_BINDstructure to one of the temporal types (MYSQL_TYPE_TIME,MYSQL_TYPE_DATE,MYSQL_TYPE_DATETIME,MYSQL_TYPE_TIMESTAMP).The
MYSQL_TIMEstructure contains the members listed in the following table.Member Description unsigned int yearThe year unsigned int monthThe month of the year unsigned int dayThe day of the month unsigned int hourThe hour of the day unsigned int minuteThe minute of the hour unsigned int secondThe second of the minute bool negA boolean flag indicating whether the time is negative unsigned long second_partThe fractional part of the second in microseconds Only those parts of a
MYSQL_TIMEstructure that apply to a given type of temporal value are used. Theyear,month, anddayelements are used forDATE,DATETIME, andTIMESTAMPvalues. Thehour,minute, andsecondelements are used forTIME,DATETIME, andTIMESTAMPvalues. See Section 3.6.4, “Prepared Statement Handling of Date and Time Values”.