pg_stat_statementspg_stat_statements
The pg_stat_statements module provides a means for
tracking execution statistics of all SQL statements executed by a server.
The module must be loaded by adding pg_stat_statements> to
in
postgresql.conf>, because it requires additional shared memory.
This means that a server restart is needed to add or remove the module.
The pg_stat_statements View
The statistics gathered by the module are made available via a
system view named pg_stat_statements>. This view
contains one row for each distinct database ID, user ID and query
ID (up to the maximum number of distinct statements that the module
can track). The columns of the view are shown in
.
pg_stat_statements> ColumnsNameTypeReferencesDescriptionuseridoidpg_authid.oidOID of user who executed the statementdbidoidpg_database.oidOID of database in which the statement was executedqueryidbigintInternal hash code, computed from the statement's parse treequerytextText of a representative statementcallsbigintNumber of times executedtotal_timedouble precisionTotal time spent in the statement, in millisecondsrowsbigintTotal number of rows retrieved or affected by the statementshared_blks_hitbigintTotal number of shared block cache hits by the statementshared_blks_readbigintTotal number of shared blocks read by the statementshared_blks_dirtiedbigintTotal number of shared blocks dirtied by the statementshared_blks_writtenbigintTotal number of shared blocks written by the statementlocal_blks_hitbigintTotal number of local block cache hits by the statementlocal_blks_readbigintTotal number of local blocks read by the statementlocal_blks_dirtiedbigintTotal number of local blocks dirtied by the statementlocal_blks_writtenbigintTotal number of local blocks written by the statementtemp_blks_readbigintTotal number of temp blocks read by the statementtemp_blks_writtenbigintTotal number of temp blocks written by the statementblk_read_timedouble precision
Total time the statement spent reading blocks, in milliseconds
(if is enabled, otherwise zero)
blk_write_timedouble precision
Total time the statement spent writing blocks, in milliseconds
(if is enabled, otherwise zero)
This view, and the functions pg_stat_statements_reset>
and pg_stat_statements>, are available only in
databases they have been specifically installed into by installing
the pg_stat_statements> extension.
However, statistics are tracked across all databases of the server
whenever the pg_stat_statements module is loaded
into the server, regardless of presence of the view.
For security reasons, non-superusers are not allowed to see the SQL
text or queryid of queries executed by other users. They can see
the statistics, however, if the view has been installed in their
database.
Plannable queries (that is, SELECT>, INSERT>,
UPDATE>, and DELETE>) are combined into a single
pg_stat_statements> entry whenever they have identical query
structures according to an internal hash calculation. Typically, two
queries will be considered the same for this purpose if they are
semantically equivalent except for the values of literal constants
appearing in the query. Utility commands (that is, all other commands)
are compared strictly on the basis of their textual query strings, however.
When a constant's value has been ignored for purposes of matching the
query to other queries, the constant is replaced by ?
in the pg_stat_statements> display. The rest of the query
text is that of the first query that had the particular
queryid> hash value associated with the
pg_stat_statements> entry.
In some cases, queries with visibly different texts might get merged into a
single pg_stat_statements> entry. Normally this will happen
only for semantically equivalent queries, but there is a small chance of
hash collisions causing unrelated queries to be merged into one entry.
(This cannot happen for queries belonging to different users or databases,
however.)
Since the queryid> hash value is computed on the
post-parse-analysis representation of the queries, the opposite is
also possible: queries with identical texts might appear as
separate entries, if they have different meanings as a result of
factors such as different search_path> settings.
Consumers of pg_stat_statements> may wish to use
queryid> (perhaps in combination with
dbid> and userid>) as a more stable
and reliable identifier for each entry than its query text.
However, it is important to understand that there are only limited
guarantees around the stability of the queryid> hash
value. Since the identifier is derived from the
post-parse-analysis tree, its value is a function of, among other
things, the internal object identifiers appearing in this representation.
This has some counterintuitive implications. For example,
pg_stat_statements> will consider two apparently-identical
queries to be distinct, if they reference a table that was dropped
and recreated between the executions of the two queries.
The hashing process is also sensitive to differences in
machine architecture and other facets of the platform.
Furthermore, it is not safe to assume that queryid>
will be stable across major versions of PostgreSQL>.
As a rule of thumb, queryid> values can be assumed to be
stable and comparable only so long as the underlying server version and
catalog metadata details stay exactly the same. Two servers
participating in replication based on physical WAL replay can be expected
to have identical queryid> values for the same query.
However, logical replication schemes do not promise to keep replicas
identical in all relevant details, so queryid> will
not be a useful identifier for accumulating costs across a set of logical
replicas. If in doubt, direct testing is recommended.
Functionspg_stat_statements_reset() returns voidpg_stat_statements_resetpg_stat_statements_reset discards all statistics
gathered so far by pg_stat_statements>.
By default, this function can only be executed by superusers.
pg_stat_statements(showtext boolean) returns setof recordpg_stat_statementsfunction
The pg_stat_statements view is defined in
terms of a function also named pg_stat_statements>.
It is possible for clients to call
the pg_stat_statements function directly, and by
specifying showtext := false have query text be
omitted (that is, the OUT argument that corresponds
to the view's query> column will return nulls). This
feature is intended to support external tools that might wish to avoid
the overhead of repeatedly retrieving query texts of indeterminate
length. Such tools can instead cache the first query text observed
for each entry themselves, since that is
all pg_stat_statements> itself does, and then retrieve
query texts only as needed. Since the server stores query texts in a
file, this approach may reduce physical I/O for repeated examination
of the pg_stat_statements data.
Configuration Parameterspg_stat_statements.max (integer)
pg_stat_statements.max is the maximum number of
statements tracked by the module (i.e., the maximum number of rows
in the pg_stat_statements> view). If more distinct
statements than that are observed, information about the least-executed
statements is discarded.
The default value is 5000.
This parameter can only be set at server start.
pg_stat_statements.track (enum)
pg_stat_statements.track controls which statements
are counted by the module.
Specify top> to track top-level statements (those issued
directly by clients), all> to also track nested statements
(such as statements invoked within functions), or none> to
disable statement statistics collection.
The default value is top>.
Only superusers can change this setting.
pg_stat_statements.track_utility (boolean)
pg_stat_statements.track_utility controls whether
utility commands are tracked by the module. Utility commands are
all those other than SELECT>, INSERT>,
UPDATE> and DELETE>.
The default value is on>.
Only superusers can change this setting.
pg_stat_statements.save (boolean)
pg_stat_statements.save specifies whether to
save statement statistics across server shutdowns.
If it is off> then statistics are not saved at
shutdown nor reloaded at server start.
The default value is on>.
This parameter can only be set in the postgresql.conf>
file or on the server command line.
The module requires additional shared memory proportional to
pg_stat_statements.max. Note that this
memory is consumed whenever the module is loaded, even if
pg_stat_statements.track> is set to none>.
These parameters must be set in postgresql.conf>.
Typical usage might be:
# postgresql.conf
shared_preload_libraries = 'pg_stat_statements'
pg_stat_statements.max = 10000
pg_stat_statements.track = all
Sample Output
bench=# SELECT pg_stat_statements_reset();
$ pgbench -i bench
$ pgbench -c10 -t300 bench
bench=# \x
bench=# SELECT query, calls, total_time, rows, 100.0 * shared_blks_hit /
nullif(shared_blks_hit + shared_blks_read, 0) AS hit_percent
FROM pg_stat_statements ORDER BY total_time DESC LIMIT 5;
-[ RECORD 1 ]---------------------------------------------------------------------
query | UPDATE pgbench_branches SET bbalance = bbalance + ? WHERE bid = ?;
calls | 3000
total_time | 9609.00100000002
rows | 2836
hit_percent | 99.9778970000200936
-[ RECORD 2 ]---------------------------------------------------------------------
query | UPDATE pgbench_tellers SET tbalance = tbalance + ? WHERE tid = ?;
calls | 3000
total_time | 8015.156
rows | 2990
hit_percent | 99.9731126579631345
-[ RECORD 3 ]---------------------------------------------------------------------
query | copy pgbench_accounts from stdin
calls | 1
total_time | 310.624
rows | 100000
hit_percent | 0.30395136778115501520
-[ RECORD 4 ]---------------------------------------------------------------------
query | UPDATE pgbench_accounts SET abalance = abalance + ? WHERE aid = ?;
calls | 3000
total_time | 271.741999999997
rows | 3000
hit_percent | 93.7968855088209426
-[ RECORD 5 ]---------------------------------------------------------------------
query | alter table pgbench_accounts add primary key (aid)
calls | 1
total_time | 81.42
rows | 0
hit_percent | 34.4947735191637631
Authors
Takahiro Itagaki itagaki.takahiro@oss.ntt.co.jp.
Query normalization added by Peter Geoghegan peter@2ndquadrant.com.