Application programs should use this general outline for interacting with MySQL by means of the client library:
Initialize the MySQL client library by calling
mysql_library_init()
.Initialize a connection handler by calling
mysql_init()
and connect to the server by calling a connection-establishment function such asmysql_real_connect()
.Issue SQL statements and process their results. (The following discussion provides more information about how to do this.)
Close the connection to the MySQL server by calling
mysql_close()
.End use of the MySQL client library by calling
mysql_library_end()
.
The purpose of calling
mysql_library_init()
and
mysql_library_end()
is to provide
proper initialization and finalization of the MySQL client
library. For applications that are linked with the client library,
they provide improved memory management. If you do not call
mysql_library_end()
, a block of
memory remains allocated. (This does not increase the amount of
memory used by the application, but some memory leak detectors
will complain about it.)
In a nonmultithreaded environment, the call to
mysql_library_init()
may be
omitted, because mysql_init()
will
invoke it automatically as necessary. However,
mysql_library_init()
is not
thread-safe in a multithreaded environment, and thus neither is
mysql_init()
, which calls
mysql_library_init()
. You must
either call mysql_library_init()
prior to spawning any threads, or else use a mutex to protect the
call, whether you invoke
mysql_library_init()
or indirectly
through mysql_init()
. This should
be done prior to any other client library call.
To connect to the server, call
mysql_init()
to initialize a
connection handler, then call a connection-establishment function
such as mysql_real_connect()
with
that handler (along with other information such as the host name,
user name, and password). When you are done with the connection,
call mysql_close()
to terminate
it. Do not use the handler after it has been closed.
Upon connection,
mysql_real_connect()
sets the
reconnect
flag (part of the
MYSQL
structure) to a value of
0
. You can use the
MYSQL_OPT_RECONNECT
option (deprecated as of
MySQL 8.0.34) to mysql_options()
to control reconnection behavior. Setting the flag to
1
cause the client to attempt reconnecting to
the server before giving up if a statement cannot be performed
because of a lost connection.
Beginning with 8.0.34, the automatic reconnection feature (Section 3.6.8, “Automatic Reconnection Control”) is deprecated and subject to removal in a future release of MySQL.
While a connection is active, the client may send SQL statements
to the server using
mysql_real_query()
or
mysql_query()
. The difference
between the two is that
mysql_query()
expects the query to
be specified as a null-terminated string whereas
mysql_real_query()
expects a
counted string. If the string contains binary data (which may
include null bytes), you must use
mysql_real_query()
.
For each non-SELECT
query (for
example, INSERT
,
UPDATE
,
DELETE
), you can find out how many
rows were changed (affected) by calling
mysql_affected_rows()
.
For SELECT
queries, you retrieve
the selected rows as a result set. (Note that some statements are
SELECT
-like in that they return
rows. These include SHOW
,
DESCRIBE
, and
EXPLAIN
. Treat these statements the
same way as SELECT
statements.)
There are two ways for a client to process result sets. One way is
to retrieve the entire result set all at once by calling
mysql_store_result()
. This
function acquires from the server all the rows returned by the
query and stores them in the client. The second way is for the
client to initiate a row-by-row result set retrieval by calling
mysql_use_result()
. This function
initializes the retrieval, but does not actually get any rows from
the server.
In both cases, you access rows by calling
mysql_fetch_row()
. With
mysql_store_result()
,
mysql_fetch_row()
accesses rows
that have previously been fetched from the server. With
mysql_use_result()
,
mysql_fetch_row()
actually
retrieves the row from the server. Information about the size of
the data in each row is available by calling
mysql_fetch_lengths()
.
After you are done with a result set, call
mysql_free_result()
to free the
memory used for it.
The two retrieval mechanisms are complementary. Choose the
approach that is most appropriate for each client application. In
practice, clients tend to use
mysql_store_result()
more
commonly.
An advantage of
mysql_store_result()
is that
because the rows have all been fetched to the client, you not only
can access rows sequentially, you can move back and forth in the
result set using mysql_data_seek()
or mysql_row_seek()
to change the
current row position within the result set. You can also find out
how many rows there are by calling
mysql_num_rows()
. On the other
hand, the memory requirements for
mysql_store_result()
may be very
high for large result sets and you are more likely to encounter
out-of-memory conditions.
An advantage of mysql_use_result()
is that the client requires less memory for the result set because
it maintains only one row at a time (and because there is less
allocation overhead,
mysql_use_result()
can be faster).
Disadvantages are that you must process each row quickly to avoid
tying up the server, you do not have random access to rows within
the result set (you can only access rows sequentially), and the
number of rows in the result set is unknown until you have
retrieved them all. Furthermore, you must
retrieve all the rows even if you determine in mid-retrieval that
you've found the information you were looking for.
The API makes it possible for clients to respond appropriately to
statements (retrieving rows only as necessary) without knowing
whether the statement is a SELECT
.
You can do this by calling
mysql_store_result()
after each
mysql_real_query()
(or
mysql_query()
). If the result set
call succeeds, the statement was a
SELECT
and you can read the rows.
If the result set call fails, call
mysql_field_count()
to determine
whether a result was actually to be expected. If
mysql_field_count()
returns zero,
the statement returned no data (indicating that it was an
INSERT
,
UPDATE
,
DELETE
, and so forth), and was not
expected to return rows. If
mysql_field_count()
is nonzero,
the statement should have returned rows, but did not. This
indicates that the statement was a
SELECT
that failed. See the
description for
mysql_field_count()
for an example
of how this can be done.
Both mysql_store_result()
and
mysql_use_result()
enable you to
obtain information about the fields that make up the result set
(the number of fields, their names and types, and so forth). You
can access field information sequentially within the row by
calling mysql_fetch_field()
repeatedly, or by field number within the row by calling
mysql_fetch_field_direct()
. The
current field cursor position may be changed by calling
mysql_field_seek()
. Setting the
field cursor affects subsequent calls to
mysql_fetch_field()
. You can also
get information for fields all at once by calling
mysql_fetch_fields()
.
For detecting and reporting errors, MySQL provides access to error
information by means of the
mysql_errno()
and
mysql_error()
functions. These
return the error code or error message for the most recently
invoked function that can succeed or fail, enabling you to
determine when an error occurred and what it was.