Once a connection to a database server has been successfully established, the functions described here are used to perform SQL queries and commands.
PQexec
Submit a command to
the server and wait for the result.
PGresult *PQexec(PGconn *conn, const char *query);
Returns a PGresult pointer
or possibly a NULL pointer. A non-NULL pointer will
generally be returned except in out-of-memory conditions or
serious errors such as inability to send the command to the
backend. If a NULL is returned, it should be treated like a
PGRES_FATAL_ERROR result. Use
PQerrorMessage
to get more
information about the error.
The PGresult
structure
encapsulates the result returned by the backend. libpq application programmers should be careful
to maintain the PGresult
abstraction. Use the accessor functions below to get at the
contents of PGresult. Avoid
directly referencing the fields of the PGresult structure because they are subject
to change in the future. (Beginning in PostgreSQL 6.4, the definition of
struct PGresult is not even provided in
libpq-fe.h. If you have old code that
accesses PGresult fields directly,
you can keep using it by including libpq-int.h too, but you are encouraged to fix
the code soon.)
PQresultStatus
Returns the
result status of the command.
ExecStatusType PQresultStatus(const PGresult *res)
PQresultStatus
can return
one of the following values:
PGRES_EMPTY_QUERY -- The string sent to the backend was empty.
PGRES_COMMAND_OK -- Successful completion of a command returning no data
PGRES_TUPLES_OK -- The query successfully executed
PGRES_COPY_OUT -- Copy Out (from server) data transfer started
PGRES_COPY_IN -- Copy In (to server) data transfer started
PGRES_BAD_RESPONSE -- The server's response was not understood
PGRES_NONFATAL_ERROR
PGRES_FATAL_ERROR
If the result status is PGRES_TUPLES_OK, then the routines described below can be used to retrieve the rows returned by the query. Note that a SELECT command that happens to retrieve zero rows still shows PGRES_TUPLES_OK. PGRES_COMMAND_OK is for commands that can never return rows (INSERT, UPDATE, etc.). A response of PGRES_EMPTY_QUERY often exposes a bug in the client software.
PQresStatus
Converts the
enumerated type returned by PQresultStatus
into a string constant
describing the status code.
char *PQresStatus(ExecStatusType status);
PQresultErrorMessage
returns the error message associated with the query, or an
empty string if there was no error.
char *PQresultErrorMessage(const PGresult *res);
Immediately following a PQexec
or PQgetResult
call, PQerrorMessage
(on the connection) will
return the same string as PQresultErrorMessage
(on the result).
However, a PGresult will retain
its error message until destroyed, whereas the connection's
error message will change when subsequent operations are
done. Use PQresultErrorMessage
when you want to
know the status associated with a particular PGresult; use PQerrorMessage
when you want to know the
status from the latest operation on the connection.
PQclear
Frees the storage
associated with the PGresult.
Every query result should be freed via PQclear
when it is no longer needed.
void PQclear(PQresult *res);
You can keep a PGresult
object around for as long as you need it; it does not go
away when you issue a new query, nor even if you close the
connection. To get rid of it, you must call PQclear
. Failure to do this will result
in memory leaks in the frontend application.
PQmakeEmptyPGresult
Constructs an empty PGresult
object with the given status.
PGresult* PQmakeEmptyPGresult(PGconn *conn, ExecStatusType status);
This is libpq's
internal routine to allocate and initialize an empty
PGresult object. It is exported
because some applications find it useful to generate result
objects (particularly objects with error status)
themselves. If conn
is not
NULL and status indicates an error, the connection's
current error message is copied into the PGresult. Note that PQclear
should eventually be called on
the object, just as with a PGresult returned by libpq itself.
PQescapeStringConn
escapes a
string for use within an SQL command. This is useful when
inserting data values as literal constants in SQL commands.
Certain characters (such as quotes and backslashes) must be
escaped to prevent them from being interpreted specially by the
SQL parser. PQescapeStringConn
performs this operation.
Tip: It is especially important to do proper escaping when handling strings that were received from an untrustworthy source. Otherwise there is a security risk: you are vulnerable to "SQL injection" attacks wherein unwanted SQL commands are fed to your database.
size_t PQescapeStringConn (PGconn *conn, char *to, const char *from, size_t length, int *error);
PQescapeStringConn
writes an
escaped version of the from
string to the to
buffer,
escaping special characters so that they cannot cause any harm,
and adding a terminating zero byte. The single quotes that must
surround PostgreSQL string
literals are not included in the result string; they should be
provided in the SQL command that the result is inserted into.
The parameter from
points to the
first character of the string that is to be escaped, and the
length
parameter gives the
number of bytes in this string. A terminating zero byte is not
required, and should not be counted in length
. (If a terminating zero byte is found
before length
bytes are
processed, PQescapeStringConn
stops at the zero; the behavior is thus rather like
strncpy
.) to
shall point to a buffer that is able to
hold at least one more byte than twice the value of
length
, otherwise the behavior
is undefined. Behavior is likewise undefined if the
to
and from
strings overlap.
If the error
parameter is not
NULL, then *error is set to zero on
success, nonzero on error. Presently the only possible error
conditions involve invalid multibyte encoding in the source
string. The output string is still generated on error, but it
can be expected that the server will reject it as malformed. On
error, a suitable message is stored in the conn
object, whether or not error
is NULL.
PQescapeStringConn
returns the
number of bytes written to to
,
not including the terminating zero byte.
size_t PQescapeString (char *to, const char *from, size_t length);
PQescapeString
is an older,
deprecated version of PQescapeStringConn
; the difference is that it
does not take conn
or
error
parameters. Because of
this, it cannot adjust its behavior depending on the connection
properties (such as character encoding) and therefore
it may give the wrong
results. Also, it has no way to report error
conditions.
PQescapeString
can be used
safely in single-threaded client programs that work with only
one PostgreSQL connection at a
time (in this case it can find out what it needs to know
"behind the scenes"). In other
contexts it is a security hazard and should be avoided in favor
of PQescapeStringConn
.
PQescapeByteaConn
Escapes binary data for use within an SQL command with the type bytea.
unsigned char *PQescapeByteaConn(PGconn *conn, const unsigned char *from, size_t from_length, size_t *to_length);
Certain byte values must be escaped (but all
byte values can
be escaped) when used as part of a bytea literal in an SQL statement. In general, to escape
a byte, it is converted into the three digit octal number
equal to the octet value, and preceded by one or two
backslashes. The single quote (') and backslash (\) characters have special alternative
escape sequences. PQescapeByteaConn
performs this
operation, escaping only the minimally required
bytes.
The from
parameter
points to the first byte of the string that is to be
escaped, and the from_length
parameter gives the number
of bytes in this binary string. (A terminating zero byte
is neither necessary nor counted.) The to_length
parameter points to a
variable that will hold the resultant escaped string
length. This result string length includes the
terminating zero byte of the result.
PQescapeByteaConn
returns an escaped version of the from
parameter binary string in memory
allocated with malloc()
.
This memory must be freed using free()
when the result is no longer
needed. The return string has all special characters
replaced so that they can be properly processed by the
PostgreSQL string
literal parser, and the bytea input
function. A terminating zero byte is also added. The
single quotes that must surround PostgreSQL string literals are not
part of the result string.
On error, a NULL pointer is returned, and a suitable
error message is stored in the conn
object. Currently, the only
possible error is insufficient memory for the result
string.
PQescapeBytea
PQescapeBytea
is an
older, deprecated version of PQescapeByteaConn
.
unsigned char *PQescapeBytea(unsigned char *from, size_t from_length, size_t *to_length);
The only difference from PQescapeByteaConn
is that PQescapeBytea
does not take a
PGconn parameter. Because of
this, it cannot adjust its behavior depending on the
connection properties and therefore it may give the wrong
results. Also, it has no way to return an error
message on failure.
PQescapeBytea
can be
used safely in single-threaded client programs that work
with only one PostgreSQL
connection at a time (in this case it can find out what
it needs to know "behind the
scenes"). In other contexts it is a security
hazard and should be avoided in favor of PQescapeByteaConn
.
PQunescapeBytea
Converts a string representation of binary data into
binary data --- the reverse of PQescapeBytea
. This is needed when
retrieving bytea data in text
format, but not when retrieving it in binary format.
unsigned char *PQunescapeBytea(unsigned char *from, size_t *to_length);
The from
parameter
points to a string such as might be returned by
PQgetvalue
when applied to
a bytea column. PQunescapeBytea
converts this string
representation into its binary representation. It returns
a pointer to a buffer allocated with malloc()
, or null on error, and puts
the size of the buffer in to_length
. The result must be freed
using free()
when it is no
longer needed.
This conversion is not exactly the inverse of
PQescapeBytea
, because the
string is not expected to be "escaped" when received from PQgetvalue
. In particular this means
there is no need for string quoting considerations, and
so no need for a PGconn
parameter.
PQntuples
Returns the
number of tuples (rows) in the query result.
int PQntuples(const PGresult *res);
PQnfields
Returns the
number of fields (columns) in each row of the query
result.
int PQnfields(const PGresult *res);
PQfname
Returns the field
(column) name associated with the given field index. Field
indices start at 0.
char *PQfname(const PGresult *res, int field_index);
PQfnumber
Returns the
field (column) index associated with the given field
name.
int PQfnumber(const PGresult *res, const char *field_name);
-1 is returned if the given name does not match any field.
PQftype
Returns the field
type associated with the given field index. The integer
returned is an internal coding of the type. Field indices
start at 0.
Oid PQftype(const PGresult *res, int field_index);
You can query the system table pg_type to obtain the name and properties of the various data types. The OIDs of the built-in data types are defined in src/include/catalog/pg_type.h in the source tree.
PQfmod
Returns the
type-specific modification data of the field associated
with the given field index. Field indices start at 0.
int PQfmod(const PGresult *res, int field_index);
PQfsize
Returns the size
in bytes of the field associated with the given field
index. Field indices start at 0.
int PQfsize(const PGresult *res, int field_index);
PQfsize
returns the space
allocated for this field in a database tuple, in other
words the size of the server's binary representation of the
data type. -1 is returned if the field is variable
size.
PQbinaryTuples
Returns 1
if the PGresult contains binary
tuple data, 0 if it contains ASCII data.
int PQbinaryTuples(const PGresult *res);
Currently, binary tuple data can only be returned by a query that extracts data from a binary cursor.
PQgetvalue
Returns a
single field (column) value of one tuple (row) of a
PGresult. Tuple and field
indices start at 0.
char* PQgetvalue(const PGresult *res, int tup_num, int field_num);
For most queries, the value returned by PQgetvalue
is a null-terminated character
string representation of the attribute value. But if
PQbinaryTuples()
is 1, the
value returned by PQgetvalue
is the binary representation of the type in the internal
format of the backend server (but not including the size
word, if the field is variable-length). It is then the
programmer's responsibility to cast and convert the data to
the correct C type. The pointer returned by PQgetvalue
points to storage that is part
of the PGresult structure. One
should not modify it, and one must explicitly copy the
value into other storage if it is to be used past the
lifetime of the PGresult
structure itself.
PQgetisnull
Tests a field
for a NULL entry. Tuple and field indices start at 0.
int PQgetisnull(const PGresult *res, int tup_num, int field_num);
This function returns 1 if the field contains a NULL, 0
if it contains a non-null value. (Note that PQgetvalue
will return an empty string,
not a null pointer, for a NULL field.)
PQgetlength
Returns the
length of a field (attribute) value in bytes. Tuple and
field indices start at 0.
int PQgetlength(const PGresult *res, int tup_num, int field_num);
This is the actual data length for the particular data
value, that is the size of the object pointed to by
PQgetvalue
. Note that for
character-represented values, this size has little to do
with the binary size reported by PQfsize
.
PQprint
Prints out all the
tuples and, optionally, the attribute names to the
specified output stream.
void PQprint(FILE* fout, /* output stream */ const PGresult *res, const PQprintOpt *po); struct { pqbool header; /* print output field headings and row count */ pqbool align; /* fill align the fields */ pqbool standard; /* old brain dead format */ pqbool html3; /* output html tables */ pqbool expanded; /* expand tables */ pqbool pager; /* use pager for output if needed */ char *fieldSep; /* field separator */ char *tableOpt; /* insert to HTML table ... */ char *caption; /* HTML caption */ char **fieldName; /* null terminated array of replacement field names */ } PQprintOpt;
This function was formerly used by psql to print query results, but this is no longer the case and this function is no longer actively supported.
PQcmdStatus
Returns the
command status string from the SQL command that generated
the PGresult.
char * PQcmdStatus(PGresult *res);
PQcmdTuples
Returns the
number of rows affected by the SQL command.
char * PQcmdTuples(PGresult *res);
If the SQL command that generated the PGresult was INSERT, UPDATE or DELETE, this returns a string containing the number of rows affected. If the command was anything else, it returns the empty string.
PQoidValue
Returns the
object ID of the inserted row, if the SQL command was an INSERT that inserted
exactly one row into a table that has OIDs. Otherwise,
returns InvalidOid.
Oid PQoidValue(const PGresult *res);
The type Oid and the constant InvalidOid will be defined if you include the libpq header file. They will both be some integer type.
PQoidStatus
Returns a
string with the object ID of the inserted row, if the
SQL command was an
INSERT. (The string will be 0 if
the INSERT did not insert exactly one row, or if the target
table does not have OIDs.) If the command was not an
INSERT, returns an empty string.
char * PQoidStatus(const PGresult *res);
This function is deprecated in favor of PQoidValue
and is not thread-safe.