Supported Versions: Current (16) / 15 / 14 / 13 / 12
Development Versions: devel
Unsupported versions: 11 / 10 / 9.6 / 9.5 / 9.4 / 9.3 / 9.2 / 9.1 / 9.0 / 8.4
This documentation is for an unsupported version of PostgreSQL.
You may want to view the same page for the current version, or one of the other supported versions listed above instead.

F.27. pg_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 shared_preload_libraries in postgresql.conf, because it requires additional shared memory. This means that a server restart is needed to add or remove the module.

F.27.1. 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 query text, database ID, and user ID (up to the maximum number of distinct statements that the module can track). The columns of the view are shown in Table F-24.

Table F-24. pg_stat_statements columns

Name Type References Description
userid oid pg_authid.oid OID of user who executed the statement
dbid oid pg_database.oid OID of database in which the statement was executed
query text   Text of the statement (up to track_activity_query_size bytes)
calls bigint   Number of times executed
total_time double precision   Total time spent in the statement, in seconds
rows bigint   Total number of rows retrieved or affected by the statement

This view, and the function pg_stat_statements_reset, are available only in databases they have been specifically installed into by running the pg_stat_statements.sql install script. 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 text of queries executed by other users. They can see the statistics, however, if the view has been installed in their database.

Note that statements are considered the same if they have the same text, regardless of the values of any out-of-line parameters used in the statement. Using out-of-line parameters will help to group statements together and may make the statistics more useful.

F.27.2. Functions

pg_stat_statements_reset() returns void

pg_stat_statements_reset discards all statistics gathered so far by pg_stat_statements. By default, this function can only be executed by superusers.

F.27.3. Configuration parameters

pg_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 1000. 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. The default value is top. 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 amounting to about pg_stat_statements.max * track_activity_query_size bytes. Note that this memory is consumed whenever the module is loaded, even if pg_stat_statements.track is set to none.

In order to set any of these parameters in your postgresql.conf file, you will need to add pg_stat_statements to custom_variable_classes. Typical usage might be:

# postgresql.conf
shared_preload_libraries = 'pg_stat_statements'

custom_variable_classes = 'pg_stat_statements'
pg_stat_statements.max = 10000
pg_stat_statements.track = all
  

F.27.4. Sample output

$ pgbench -i bench

postgres=# SELECT pg_stat_statements_reset();

$ pgbench -c10 -t300 -M prepared bench

postgres=# \x
postgres=# SELECT * FROM pg_stat_statements ORDER BY total_time DESC LIMIT 3;
-[ RECORD 1 ]------------------------------------------------------------
userid     | 10
dbid       | 63781
query      | UPDATE branches SET bbalance = bbalance + $1 WHERE bid = $2;
calls      | 3000
total_time | 20.716706
rows       | 3000
-[ RECORD 2 ]------------------------------------------------------------
userid     | 10
dbid       | 63781
query      | UPDATE tellers SET tbalance = tbalance + $1 WHERE tid = $2;
calls      | 3000
total_time | 17.1107649999999
rows       | 3000
-[ RECORD 3 ]------------------------------------------------------------
userid     | 10
dbid       | 63781
query      | UPDATE accounts SET abalance = abalance + $1 WHERE aid = $2;
calls      | 3000
total_time | 0.645601
rows       | 3000