|
- <?xml version="1.0" encoding="UTF-8" standalone="no"?>
- <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>F.29. pg_stat_statements</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets V1.79.1" /><link rel="prev" href="pgrowlocks.html" title="F.28. pgrowlocks" /><link rel="next" href="pgstattuple.html" title="F.30. pgstattuple" /></head><body><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">F.29. pg_stat_statements</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="pgrowlocks.html" title="F.28. pgrowlocks">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="contrib.html" title="Appendix F. Additional Supplied Modules">Up</a></td><th width="60%" align="center">Appendix F. Additional Supplied Modules</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 12.4 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="pgstattuple.html" title="F.30. pgstattuple">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="PGSTATSTATEMENTS"><div class="titlepage"><div><div><h2 class="title" style="clear: both">F.29. pg_stat_statements</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="pgstatstatements.html#id-1.11.7.38.6">F.29.1. The <code class="structname">pg_stat_statements</code> View</a></span></dt><dt><span class="sect2"><a href="pgstatstatements.html#id-1.11.7.38.7">F.29.2. Functions</a></span></dt><dt><span class="sect2"><a href="pgstatstatements.html#id-1.11.7.38.8">F.29.3. Configuration Parameters</a></span></dt><dt><span class="sect2"><a href="pgstatstatements.html#id-1.11.7.38.9">F.29.4. Sample Output</a></span></dt><dt><span class="sect2"><a href="pgstatstatements.html#id-1.11.7.38.10">F.29.5. Authors</a></span></dt></dl></div><a id="id-1.11.7.38.2" class="indexterm"></a><p>
- The <code class="filename">pg_stat_statements</code> module provides a means for
- tracking execution statistics of all SQL statements executed by a server.
- </p><p>
- The module must be loaded by adding <code class="literal">pg_stat_statements</code> to
- <a class="xref" href="runtime-config-client.html#GUC-SHARED-PRELOAD-LIBRARIES">shared_preload_libraries</a> in
- <code class="filename">postgresql.conf</code>, because it requires additional shared memory.
- This means that a server restart is needed to add or remove the module.
- </p><p>
- When <code class="filename">pg_stat_statements</code> is loaded, it tracks
- statistics across all databases of the server. To access and manipulate
- these statistics, the module provides a view, <code class="structname">pg_stat_statements</code>,
- and the utility functions <code class="function">pg_stat_statements_reset</code> and
- <code class="function">pg_stat_statements</code>. These are not available globally but
- can be enabled for a specific database with
- <code class="command">CREATE EXTENSION pg_stat_statements</code>.
- </p><div class="sect2" id="id-1.11.7.38.6"><div class="titlepage"><div><div><h3 class="title">F.29.1. The <code class="structname">pg_stat_statements</code> View</h3></div></div></div><p>
- The statistics gathered by the module are made available via a
- view named <code class="structname">pg_stat_statements</code>. 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
- <a class="xref" href="pgstatstatements.html#PGSTATSTATEMENTS-COLUMNS" title="Table F.21. pg_stat_statements Columns">Table F.21</a>.
- </p><div class="table" id="PGSTATSTATEMENTS-COLUMNS"><p class="title"><strong>Table F.21. <code class="structname">pg_stat_statements</code> Columns</strong></p><div class="table-contents"><table class="table" summary="pg_stat_statements Columns" border="1"><colgroup><col /><col /><col /><col /></colgroup><thead><tr><th>Name</th><th>Type</th><th>References</th><th>Description</th></tr></thead><tbody><tr><td><code class="structfield">userid</code></td><td><code class="type">oid</code></td><td><code class="literal"><a class="link" href="catalog-pg-authid.html" title="51.8. pg_authid"><code class="structname">pg_authid</code></a>.oid</code></td><td>OID of user who executed the statement</td></tr><tr><td><code class="structfield">dbid</code></td><td><code class="type">oid</code></td><td><code class="literal"><a class="link" href="catalog-pg-database.html" title="51.15. pg_database"><code class="structname">pg_database</code></a>.oid</code></td><td>OID of database in which the statement was executed</td></tr><tr><td><code class="structfield">queryid</code></td><td><code class="type">bigint</code></td><td> </td><td>Internal hash code, computed from the statement's parse tree</td></tr><tr><td><code class="structfield">query</code></td><td><code class="type">text</code></td><td> </td><td>Text of a representative statement</td></tr><tr><td><code class="structfield">calls</code></td><td><code class="type">bigint</code></td><td> </td><td>Number of times executed</td></tr><tr><td><code class="structfield">total_time</code></td><td><code class="type">double precision</code></td><td> </td><td>Total time spent in the statement, in milliseconds</td></tr><tr><td><code class="structfield">min_time</code></td><td><code class="type">double precision</code></td><td> </td><td>Minimum time spent in the statement, in milliseconds</td></tr><tr><td><code class="structfield">max_time</code></td><td><code class="type">double precision</code></td><td> </td><td>Maximum time spent in the statement, in milliseconds</td></tr><tr><td><code class="structfield">mean_time</code></td><td><code class="type">double precision</code></td><td> </td><td>Mean time spent in the statement, in milliseconds</td></tr><tr><td><code class="structfield">stddev_time</code></td><td><code class="type">double precision</code></td><td> </td><td>Population standard deviation of time spent in the statement, in milliseconds</td></tr><tr><td><code class="structfield">rows</code></td><td><code class="type">bigint</code></td><td> </td><td>Total number of rows retrieved or affected by the statement</td></tr><tr><td><code class="structfield">shared_blks_hit</code></td><td><code class="type">bigint</code></td><td> </td><td>Total number of shared block cache hits by the statement</td></tr><tr><td><code class="structfield">shared_blks_read</code></td><td><code class="type">bigint</code></td><td> </td><td>Total number of shared blocks read by the statement</td></tr><tr><td><code class="structfield">shared_blks_dirtied</code></td><td><code class="type">bigint</code></td><td> </td><td>Total number of shared blocks dirtied by the statement</td></tr><tr><td><code class="structfield">shared_blks_written</code></td><td><code class="type">bigint</code></td><td> </td><td>Total number of shared blocks written by the statement</td></tr><tr><td><code class="structfield">local_blks_hit</code></td><td><code class="type">bigint</code></td><td> </td><td>Total number of local block cache hits by the statement</td></tr><tr><td><code class="structfield">local_blks_read</code></td><td><code class="type">bigint</code></td><td> </td><td>Total number of local blocks read by the statement</td></tr><tr><td><code class="structfield">local_blks_dirtied</code></td><td><code class="type">bigint</code></td><td> </td><td>Total number of local blocks dirtied by the statement</td></tr><tr><td><code class="structfield">local_blks_written</code></td><td><code class="type">bigint</code></td><td> </td><td>Total number of local blocks written by the statement</td></tr><tr><td><code class="structfield">temp_blks_read</code></td><td><code class="type">bigint</code></td><td> </td><td>Total number of temp blocks read by the statement</td></tr><tr><td><code class="structfield">temp_blks_written</code></td><td><code class="type">bigint</code></td><td> </td><td>Total number of temp blocks written by the statement</td></tr><tr><td><code class="structfield">blk_read_time</code></td><td><code class="type">double precision</code></td><td> </td><td>
- Total time the statement spent reading blocks, in milliseconds
- (if <a class="xref" href="runtime-config-statistics.html#GUC-TRACK-IO-TIMING">track_io_timing</a> is enabled, otherwise zero)
- </td></tr><tr><td><code class="structfield">blk_write_time</code></td><td><code class="type">double precision</code></td><td> </td><td>
- Total time the statement spent writing blocks, in milliseconds
- (if <a class="xref" href="runtime-config-statistics.html#GUC-TRACK-IO-TIMING">track_io_timing</a> is enabled, otherwise zero)
- </td></tr></tbody></table></div></div><br class="table-break" /><p>
- For security reasons, only superusers and members of the
- <code class="literal">pg_read_all_stats</code> role are allowed to see the SQL text and
- <code class="structfield">queryid</code> of queries executed by other users.
- Other users can see the statistics, however, if the view has been installed
- in their database.
- </p><p>
- Plannable queries (that is, <code class="command">SELECT</code>, <code class="command">INSERT</code>,
- <code class="command">UPDATE</code>, and <code class="command">DELETE</code>) are combined into a single
- <code class="structname">pg_stat_statements</code> 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.
- </p><p>
- When a constant's value has been ignored for purposes of matching the query
- to other queries, the constant is replaced by a parameter symbol, such
- as <code class="literal">$1</code>, in the <code class="structname">pg_stat_statements</code>
- display.
- The rest of the query text is that of the first query that had the
- particular <code class="structfield">queryid</code> hash value associated with the
- <code class="structname">pg_stat_statements</code> entry.
- </p><p>
- In some cases, queries with visibly different texts might get merged into a
- single <code class="structname">pg_stat_statements</code> 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.)
- </p><p>
- Since the <code class="structfield">queryid</code> 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 <code class="varname">search_path</code> settings.
- </p><p>
- Consumers of <code class="structname">pg_stat_statements</code> may wish to use
- <code class="structfield">queryid</code> (perhaps in combination with
- <code class="structfield">dbid</code> and <code class="structfield">userid</code>) 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 <code class="structfield">queryid</code> 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,
- <code class="filename">pg_stat_statements</code> 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 <code class="structfield">queryid</code>
- will be stable across major versions of <span class="productname">PostgreSQL</span>.
- </p><p>
- As a rule of thumb, <code class="structfield">queryid</code> 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 <code class="structfield">queryid</code> values for the same query.
- However, logical replication schemes do not promise to keep replicas
- identical in all relevant details, so <code class="structfield">queryid</code> will
- not be a useful identifier for accumulating costs across a set of logical
- replicas. If in doubt, direct testing is recommended.
- </p><p>
- The parameter symbols used to replace constants in
- representative query texts start from the next number after the
- highest <code class="literal">$</code><em class="replaceable"><code>n</code></em> parameter in the original query
- text, or <code class="literal">$1</code> if there was none. It's worth noting that in
- some cases there may be hidden parameter symbols that affect this
- numbering. For example, <span class="application">PL/pgSQL</span> uses hidden parameter
- symbols to insert values of function local variables into queries, so that
- a <span class="application">PL/pgSQL</span> statement like <code class="literal">SELECT i + 1 INTO j</code>
- would have representative text like <code class="literal">SELECT i + $2</code>.
- </p><p>
- The representative query texts are kept in an external disk file, and do
- not consume shared memory. Therefore, even very lengthy query texts can
- be stored successfully. However, if many long query texts are
- accumulated, the external file might grow unmanageably large. As a
- recovery method if that happens, <code class="filename">pg_stat_statements</code> may
- choose to discard the query texts, whereupon all existing entries in
- the <code class="structname">pg_stat_statements</code> view will show
- null <code class="structfield">query</code> fields, though the statistics associated with
- each <code class="structfield">queryid</code> are preserved. If this happens, consider
- reducing <code class="varname">pg_stat_statements.max</code> to prevent
- recurrences.
- </p></div><div class="sect2" id="id-1.11.7.38.7"><div class="titlepage"><div><div><h3 class="title">F.29.2. Functions</h3></div></div></div><div class="variablelist"><dl class="variablelist"><dt><span class="term">
- <code class="function">pg_stat_statements_reset(userid Oid, dbid Oid, queryid bigint) returns void</code>
- <a id="id-1.11.7.38.7.2.1.1.2" class="indexterm"></a>
- </span></dt><dd><p>
- <code class="function">pg_stat_statements_reset</code> discards statistics
- gathered so far by <code class="filename">pg_stat_statements</code> corresponding
- to the specified <code class="structfield">userid</code>, <code class="structfield">dbid</code>
- and <code class="structfield">queryid</code>. If any of the parameters are not
- specified, the default value <code class="literal">0</code>(invalid) is used for
- each of them and the statistics that match with other parameters will be
- reset. If no parameter is specified or all the specified parameters are
- <code class="literal">0</code>(invalid), it will discard all statistics. By
- default, this function can only be executed by superusers. Access may be
- granted to others using <code class="command">GRANT</code>.
- </p></dd><dt><span class="term">
- <code class="function">pg_stat_statements(showtext boolean) returns setof record</code>
- <a id="id-1.11.7.38.7.2.2.1.2" class="indexterm"></a>
- </span></dt><dd><p>
- The <code class="structname">pg_stat_statements</code> view is defined in
- terms of a function also named <code class="function">pg_stat_statements</code>.
- It is possible for clients to call
- the <code class="function">pg_stat_statements</code> function directly, and by
- specifying <code class="literal">showtext := false</code> have query text be
- omitted (that is, the <code class="literal">OUT</code> argument that corresponds
- to the view's <code class="structfield">query</code> 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 <code class="filename">pg_stat_statements</code> 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 <code class="structname">pg_stat_statements</code> data.
- </p></dd></dl></div></div><div class="sect2" id="id-1.11.7.38.8"><div class="titlepage"><div><div><h3 class="title">F.29.3. Configuration Parameters</h3></div></div></div><div class="variablelist"><dl class="variablelist"><dt><span class="term">
- <code class="varname">pg_stat_statements.max</code> (<code class="type">integer</code>)
- </span></dt><dd><p>
- <code class="varname">pg_stat_statements.max</code> is the maximum number of
- statements tracked by the module (i.e., the maximum number of rows
- in the <code class="structname">pg_stat_statements</code> 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.
- </p></dd><dt><span class="term">
- <code class="varname">pg_stat_statements.track</code> (<code class="type">enum</code>)
- </span></dt><dd><p>
- <code class="varname">pg_stat_statements.track</code> controls which statements
- are counted by the module.
- Specify <code class="literal">top</code> to track top-level statements (those issued
- directly by clients), <code class="literal">all</code> to also track nested statements
- (such as statements invoked within functions), or <code class="literal">none</code> to
- disable statement statistics collection.
- The default value is <code class="literal">top</code>.
- Only superusers can change this setting.
- </p></dd><dt><span class="term">
- <code class="varname">pg_stat_statements.track_utility</code> (<code class="type">boolean</code>)
- </span></dt><dd><p>
- <code class="varname">pg_stat_statements.track_utility</code> controls whether
- utility commands are tracked by the module. Utility commands are
- all those other than <code class="command">SELECT</code>, <code class="command">INSERT</code>,
- <code class="command">UPDATE</code> and <code class="command">DELETE</code>.
- The default value is <code class="literal">on</code>.
- Only superusers can change this setting.
- </p></dd><dt><span class="term">
- <code class="varname">pg_stat_statements.save</code> (<code class="type">boolean</code>)
- </span></dt><dd><p>
- <code class="varname">pg_stat_statements.save</code> specifies whether to
- save statement statistics across server shutdowns.
- If it is <code class="literal">off</code> then statistics are not saved at
- shutdown nor reloaded at server start.
- The default value is <code class="literal">on</code>.
- This parameter can only be set in the <code class="filename">postgresql.conf</code>
- file or on the server command line.
- </p></dd></dl></div><p>
- The module requires additional shared memory proportional to
- <code class="varname">pg_stat_statements.max</code>. Note that this
- memory is consumed whenever the module is loaded, even if
- <code class="varname">pg_stat_statements.track</code> is set to <code class="literal">none</code>.
- </p><p>
- These parameters must be set in <code class="filename">postgresql.conf</code>.
- Typical usage might be:
-
- </p><pre class="programlisting">
- # postgresql.conf
- shared_preload_libraries = 'pg_stat_statements'
-
- pg_stat_statements.max = 10000
- pg_stat_statements.track = all
- </pre><p>
- </p></div><div class="sect2" id="id-1.11.7.38.9"><div class="titlepage"><div><div><h3 class="title">F.29.4. Sample Output</h3></div></div></div><pre class="screen">
- 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 + $1 WHERE bid = $2
- calls | 3000
- total_time | 25565.855387
- rows | 3000
- hit_percent | 100.0000000000000000
- -[ RECORD 2 ]--------------------------------------------------------------------
- query | UPDATE pgbench_tellers SET tbalance = tbalance + $1 WHERE tid = $2
- calls | 3000
- total_time | 20756.669379
- rows | 3000
- hit_percent | 100.0000000000000000
- -[ RECORD 3 ]--------------------------------------------------------------------
- query | copy pgbench_accounts from stdin
- calls | 1
- total_time | 291.865911
- rows | 100000
- hit_percent | 100.0000000000000000
- -[ RECORD 4 ]--------------------------------------------------------------------
- query | UPDATE pgbench_accounts SET abalance = abalance + $1 WHERE aid = $2
- calls | 3000
- total_time | 271.232977
- rows | 3000
- hit_percent | 98.5723926698852723
- -[ RECORD 5 ]--------------------------------------------------------------------
- query | alter table pgbench_accounts add primary key (aid)
- calls | 1
- total_time | 160.588563
- rows | 0
- hit_percent | 100.0000000000000000
-
-
- bench=# SELECT pg_stat_statements_reset(0,0,s.queryid) FROM pg_stat_statements AS s
- WHERE s.query = 'UPDATE pgbench_branches SET bbalance = bbalance + $1 WHERE bid = $2';
-
- 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_tellers SET tbalance = tbalance + $1 WHERE tid = $2
- calls | 3000
- total_time | 20756.669379
- rows | 3000
- hit_percent | 100.0000000000000000
- -[ RECORD 2 ]--------------------------------------------------------------------
- query | copy pgbench_accounts from stdin
- calls | 1
- total_time | 291.865911
- rows | 100000
- hit_percent | 100.0000000000000000
- -[ RECORD 3 ]--------------------------------------------------------------------
- query | UPDATE pgbench_accounts SET abalance = abalance + $1 WHERE aid = $2
- calls | 3000
- total_time | 271.232977
- rows | 3000
- hit_percent | 98.5723926698852723
- -[ RECORD 4 ]--------------------------------------------------------------------
- query | alter table pgbench_accounts add primary key (aid)
- calls | 1
- total_time | 160.588563
- rows | 0
- hit_percent | 100.0000000000000000
- -[ RECORD 5 ]--------------------------------------------------------------------
- query | vacuum analyze pgbench_accounts
- calls | 1
- total_time | 136.448116
- rows | 0
- hit_percent | 99.9201915403032721
-
- bench=# SELECT pg_stat_statements_reset(0,0,0);
-
- 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 | SELECT pg_stat_statements_reset(0,0,0)
- calls | 1
- total_time | 0.189497
- rows | 1
- hit_percent |
-
- </pre></div><div class="sect2" id="id-1.11.7.38.10"><div class="titlepage"><div><div><h3 class="title">F.29.5. Authors</h3></div></div></div><p>
- Takahiro Itagaki <code class="email"><<a class="email" href="mailto:itagaki.takahiro@oss.ntt.co.jp">itagaki.takahiro@oss.ntt.co.jp</a>></code>.
- Query normalization added by Peter Geoghegan <code class="email"><<a class="email" href="mailto:peter@2ndquadrant.com">peter@2ndquadrant.com</a>></code>.
- </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="pgrowlocks.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="contrib.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="pgstattuple.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">F.28. pgrowlocks </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> F.30. pgstattuple</td></tr></table></div></body></html>
|