pgstatstatements.sgml 31.8 KB
Newer Older
1
<!-- doc/src/sgml/pgstatstatements.sgml -->
2

3
<sect1 id="pgstatstatements" xreflabel="pg_stat_statements">
4 5 6 7 8 9 10 11
 <title>pg_stat_statements</title>

 <indexterm zone="pgstatstatements">
  <primary>pg_stat_statements</primary>
 </indexterm>

 <para>
  The <filename>pg_stat_statements</filename> module provides a means for
12 13
  tracking planning and execution statistics of all SQL statements executed by
  a server.
14 15 16
 </para>

 <para>
17
  The module must be loaded by adding <literal>pg_stat_statements</literal> to
18
  <xref linkend="guc-shared-preload-libraries"/> in
19
  <filename>postgresql.conf</filename>, because it requires additional shared memory.
20
  This means that a server restart is needed to add or remove the module.
21 22 23 24
  In addition, query identifier calculation must be enabled in order for the
  module to be active, which is done automatically if <xref linkend="guc-compute-query-id"/>
  is set to <literal>auto</literal> or <literal>on</literal>, or any third-party
  module that calculates query identifiers is loaded.
25 26
 </para>

27
 <para>
28
   When <filename>pg_stat_statements</filename> is active, it tracks
29
   statistics across all databases of the server.  To access and manipulate
30 31 32
   these statistics, the module provides views
   <structname>pg_stat_statements</structname> and
   <structname>pg_stat_statements_info</structname>,
33 34
   and the utility functions <function>pg_stat_statements_reset</function> and
   <function>pg_stat_statements</function>.  These are not available globally but
35
   can be enabled for a specific database with
36
   <command>CREATE EXTENSION pg_stat_statements</command>.
37 38
 </para>

39
 <sect2>
40
  <title>The <structname>pg_stat_statements</structname> View</title>
41 42

  <para>
43
   The statistics gathered by the module are made available via a
44
   view named <structname>pg_stat_statements</structname>.  This view
45 46
   contains one row for each distinct database ID, user ID, query ID and
   toplevel (up to the maximum number of distinct statements that the module
47
   can track).  The columns of the view are shown in
48
   <xref linkend="pgstatstatements-columns"/>.
49 50
  </para>

51
  <table id="pgstatstatements-columns">
52
   <title><structname>pg_stat_statements</structname> Columns</title>
53
   <tgroup cols="1">
54 55
    <thead>
     <row>
56 57 58 59 60 61
      <entry role="catalog_table_entry"><para role="column_definition">
       Column Type
      </para>
      <para>
       Description
      </para></entry>
62 63
     </row>
    </thead>
64

65 66
    <tbody>
     <row>
67 68 69 70 71 72 73
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>userid</structfield> <type>oid</type>
       (references <link linkend="catalog-pg-authid"><structname>pg_authid</structname></link>.<structfield>oid</structfield>)
      </para>
      <para>
       OID of user who executed the statement
      </para></entry>
74 75 76
     </row>

     <row>
77 78 79 80 81 82 83
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>dbid</structfield> <type>oid</type>
       (references <link linkend="catalog-pg-database"><structname>pg_database</structname></link>.<structfield>oid</structfield>)
      </para>
      <para>
       OID of database in which the statement was executed
      </para></entry>
84 85
     </row>

86 87 88 89 90 91
     <row>
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>toplevel</structfield> <type>bool</type>
      </para>
      <para>
       True if the query was executed as a top level statement
92 93
       (always true if <varname>pg_stat_statements.track</varname> is set to
       <literal>top</literal>)
94 95 96
      </para></entry>
     </row>

97
     <row>
98 99 100 101
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>queryid</structfield> <type>bigint</type>
      </para>
      <para>
102
       Hash code to identify identical normalized queries.
103
      </para></entry>
104 105 106
     </row>

     <row>
107 108 109 110 111 112
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>query</structfield> <type>text</type>
      </para>
      <para>
       Text of a representative statement
      </para></entry>
113 114
     </row>

115
     <row>
116 117 118 119 120
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>plans</structfield> <type>bigint</type>
      </para>
      <para>
       Number of times the statement was planned
121 122
       (if <varname>pg_stat_statements.track_planning</varname> is enabled,
       otherwise zero)
123
      </para></entry>
124 125 126
     </row>

     <row>
127 128 129 130 131
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>total_plan_time</structfield> <type>double precision</type>
      </para>
      <para>
       Total time spent planning the statement, in milliseconds
132 133
       (if <varname>pg_stat_statements.track_planning</varname> is enabled,
       otherwise zero)
134
      </para></entry>
135 136 137
     </row>

     <row>
138 139 140 141 142
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>min_plan_time</structfield> <type>double precision</type>
      </para>
      <para>
       Minimum time spent planning the statement, in milliseconds
143 144
       (if <varname>pg_stat_statements.track_planning</varname> is enabled,
       otherwise zero)
145
      </para></entry>
146 147 148
     </row>

     <row>
149 150 151 152 153
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>max_plan_time</structfield> <type>double precision</type>
      </para>
      <para>
       Maximum time spent planning the statement, in milliseconds
154 155
       (if <varname>pg_stat_statements.track_planning</varname> is enabled,
       otherwise zero)
156
      </para></entry>
157 158 159
     </row>

     <row>
160 161 162 163 164
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>mean_plan_time</structfield> <type>double precision</type>
      </para>
      <para>
       Mean time spent planning the statement, in milliseconds
165 166
       (if <varname>pg_stat_statements.track_planning</varname> is enabled,
       otherwise zero)
167
      </para></entry>
168 169 170
     </row>

     <row>
171 172 173 174
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>stddev_plan_time</structfield> <type>double precision</type>
      </para>
      <para>
175 176 177 178
       Population standard deviation of time spent planning the statement,
       in milliseconds
       (if <varname>pg_stat_statements.track_planning</varname> is enabled,
       otherwise zero)
179
      </para></entry>
180 181
     </row>

182
     <row>
183 184 185 186 187 188
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>calls</structfield> <type>bigint</type>
      </para>
      <para>
       Number of times the statement was executed
      </para></entry>
189 190 191
     </row>

     <row>
192 193 194 195 196 197
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>total_exec_time</structfield> <type>double precision</type>
      </para>
      <para>
       Total time spent executing the statement, in milliseconds
      </para></entry>
198 199
     </row>

200
     <row>
201 202 203 204 205 206
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>min_exec_time</structfield> <type>double precision</type>
      </para>
      <para>
       Minimum time spent executing the statement, in milliseconds
      </para></entry>
207 208 209
     </row>

     <row>
210 211 212 213 214 215
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>max_exec_time</structfield> <type>double precision</type>
      </para>
      <para>
       Maximum time spent executing the statement, in milliseconds
      </para></entry>
216 217 218
     </row>

     <row>
219 220 221 222 223 224
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>mean_exec_time</structfield> <type>double precision</type>
      </para>
      <para>
       Mean time spent executing the statement, in milliseconds
      </para></entry>
225 226 227
     </row>

     <row>
228 229 230 231 232 233
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>stddev_exec_time</structfield> <type>double precision</type>
      </para>
      <para>
       Population standard deviation of time spent executing the statement, in milliseconds
      </para></entry>
234 235
     </row>

236
     <row>
237 238 239 240 241 242
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>rows</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of rows retrieved or affected by the statement
      </para></entry>
243 244
     </row>

245
     <row>
246 247 248 249 250 251
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>shared_blks_hit</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of shared block cache hits by the statement
      </para></entry>
252 253 254
     </row>

     <row>
255 256 257 258 259 260
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>shared_blks_read</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of shared blocks read by the statement
      </para></entry>
261 262
     </row>

263
     <row>
264 265 266 267 268 269
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>shared_blks_dirtied</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of shared blocks dirtied by the statement
      </para></entry>
270 271
     </row>

272
     <row>
273 274 275 276 277 278
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>shared_blks_written</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of shared blocks written by the statement
      </para></entry>
279 280 281
     </row>

     <row>
282 283 284 285 286 287
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>local_blks_hit</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of local block cache hits by the statement
      </para></entry>
288 289 290
     </row>

     <row>
291 292 293 294 295 296
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>local_blks_read</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of local blocks read by the statement
      </para></entry>
297 298
     </row>

299
     <row>
300 301 302 303 304 305
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>local_blks_dirtied</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of local blocks dirtied by the statement
      </para></entry>
306 307
     </row>

308
     <row>
309 310 311 312 313 314
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>local_blks_written</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of local blocks written by the statement
      </para></entry>
315 316 317
     </row>

     <row>
318 319 320 321 322 323
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>temp_blks_read</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of temp blocks read by the statement
      </para></entry>
324 325 326
     </row>

     <row>
327 328 329 330 331 332
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>temp_blks_written</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of temp blocks written by the statement
      </para></entry>
333 334
     </row>

335
     <row>
336 337 338 339 340 341 342
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>blk_read_time</structfield> <type>double precision</type>
      </para>
      <para>
       Total time the statement spent reading blocks, in milliseconds
       (if <xref linkend="guc-track-io-timing"/> is enabled, otherwise zero)
      </para></entry>
343 344 345
     </row>

     <row>
346 347 348 349 350 351 352
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>blk_write_time</structfield> <type>double precision</type>
      </para>
      <para>
       Total time the statement spent writing blocks, in milliseconds
       (if <xref linkend="guc-track-io-timing"/> is enabled, otherwise zero)
      </para></entry>
353 354
     </row>

355
     <row>
356 357 358 359 360 361
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>wal_records</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of WAL records generated by the statement
      </para></entry>
362 363 364
     </row>

     <row>
365 366 367 368 369 370
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>wal_fpi</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of WAL full page images generated by the statement
      </para></entry>
371 372 373
     </row>

     <row>
374 375 376 377
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>wal_bytes</structfield> <type>numeric</type>
      </para>
      <para>
378
       Total amount of WAL generated by the statement in bytes
379
      </para></entry>
380
     </row>
381 382 383 384 385
    </tbody>
   </tgroup>
  </table>

  <para>
Simon Riggs's avatar
Simon Riggs committed
386
   For security reasons, only superusers and members of the
Tom Lane's avatar
Tom Lane committed
387
   <literal>pg_read_all_stats</literal> role are allowed to see the SQL text and
Simon Riggs's avatar
Simon Riggs committed
388 389 390
   <structfield>queryid</structfield> of queries executed by other users.
   Other users can see the statistics, however, if the view has been installed
   in their database.
391 392 393
  </para>

  <para>
394 395 396
   Plannable queries (that is, <command>SELECT</command>, <command>INSERT</command>,
   <command>UPDATE</command>, and <command>DELETE</command>) are combined into a single
   <structname>pg_stat_statements</structname> entry whenever they have identical query
397 398 399 400 401 402 403
   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.
  </para>

404 405 406
  <note>
   <para>
    The following details about constant replacement and
407
    <structfield>queryid</structfield> only apply when <xref
408 409 410 411 412 413
    linkend="guc-compute-query-id"/> is enabled.  If you use an external
    module instead to compute <structfield>queryid</structfield>, you
    should refer to its documentation for details.
   </para>
  </note>

414
  <para>
415 416
   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
417
   as <literal>$1</literal>, in the <structname>pg_stat_statements</structname>
418 419
   display.
   The rest of the query text is that of the first query that had the
420 421
   particular <structfield>queryid</structfield> hash value associated with the
   <structname>pg_stat_statements</structname> entry.
422 423 424 425
  </para>

  <para>
   In some cases, queries with visibly different texts might get merged into a
426
   single <structname>pg_stat_statements</structname> entry.  Normally this will happen
427 428 429 430 431 432 433
   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.)
  </para>

  <para>
434
   Since the <structfield>queryid</structfield> hash value is computed on the
435 436 437
   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
438
   factors such as different <varname>search_path</varname> settings.
439 440 441
  </para>

  <para>
442 443 444
   Consumers of <structname>pg_stat_statements</structname> may wish to use
   <structfield>queryid</structfield> (perhaps in combination with
   <structfield>dbid</structfield> and <structfield>userid</structfield>) as a more stable
445 446
   and reliable identifier for each entry than its query text.
   However, it is important to understand that there are only limited
447
   guarantees around the stability of the <structfield>queryid</structfield> hash
448 449
   value.  Since the identifier is derived from the
   post-parse-analysis tree, its value is a function of, among other
450 451
   things, the internal object identifiers appearing in this representation.
   This has some counterintuitive implications.  For example,
452
   <filename>pg_stat_statements</filename> will consider two apparently-identical
453 454 455
   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
456
   machine architecture and other facets of the platform.
457 458
   Furthermore, it is not safe to assume that <structfield>queryid</structfield>
   will be stable across major versions of <productname>PostgreSQL</productname>.
459 460 461
  </para>

  <para>
462
   As a rule of thumb, <structfield>queryid</structfield> values can be assumed to be
463 464 465
   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
466
   to have identical <structfield>queryid</structfield> values for the same query.
467
   However, logical replication schemes do not promise to keep replicas
468
   identical in all relevant details, so <structfield>queryid</structfield> will
469 470
   not be a useful identifier for accumulating costs across a set of logical
   replicas.  If in doubt, direct testing is recommended.
471
  </para>
472

473 474 475
  <para>
   The parameter symbols used to replace constants in
   representative query texts start from the next number after the
476 477
   highest <literal>$</literal><replaceable>n</replaceable> parameter in the original query
   text, or <literal>$1</literal> if there was none.  It's worth noting that in
478
   some cases there may be hidden parameter symbols that affect this
479
   numbering.  For example, <application>PL/pgSQL</application> uses hidden parameter
480
   symbols to insert values of function local variables into queries, so that
481 482
   a <application>PL/pgSQL</application> statement like <literal>SELECT i + 1 INTO j</literal>
   would have representative text like <literal>SELECT i + $2</literal>.
483 484
  </para>

485 486 487 488 489
  <para>
   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
490
   recovery method if that happens, <filename>pg_stat_statements</filename> may
491
   choose to discard the query texts, whereupon all existing entries in
492 493 494
   the <structname>pg_stat_statements</structname> view will show
   null <structfield>query</structfield> fields, though the statistics associated with
   each <structfield>queryid</structfield> are preserved.  If this happens, consider
495 496 497
   reducing <varname>pg_stat_statements.max</varname> to prevent
   recurrences.
  </para>
498 499 500 501 502 503 504 505 506 507

  <para>
   <structfield>plans</structfield> and <structfield>calls</structfield> aren't
   always expected to match because planning and execution statistics are
   updated at their respective end phase, and only for successful operations.
   For example, if a statement is successfully planned but fails during
   the execution phase, only its planning statistics will be updated.
   If planning is skipped because a cached plan is used, only its execution
   statistics will be updated.
  </para>
508 509
 </sect2>

510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550
 <sect2>
  <title>The <structname>pg_stat_statements_info</structname> View</title>

  <indexterm>
   <primary>pg_stat_statements_info</primary>
  </indexterm>

  <para>
   The statistics of the <filename>pg_stat_statements</filename> module
   itself are tracked and made available via a view named
   <structname>pg_stat_statements_info</structname>.  This view contains
   only a single row.  The columns of the view are shown in
   <xref linkend="pgstatstatementsinfo-columns"/>.
  </para>

  <table id="pgstatstatementsinfo-columns">
   <title><structname>pg_stat_statements_info</structname> Columns</title>
   <tgroup cols="1">
    <thead>
     <row>
      <entry role="catalog_table_entry"><para role="column_definition">
       Column Type
      </para>
      <para>
       Description
      </para></entry>
     </row>
    </thead>

    <tbody>
     <row>
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>dealloc</structfield> <type>bigint</type>
      </para>
      <para>
       Total number of times <structname>pg_stat_statements</structname>
       entries about the least-executed statements were deallocated
       because more distinct statements than
       <varname>pg_stat_statements.max</varname> were observed
      </para></entry>
     </row>
551 552 553 554 555 556 557 558 559 560
     <row>
      <entry role="catalog_table_entry"><para role="column_definition">
       <structfield>stats_reset</structfield> <type>timestamp with time zone</type>
      </para>
      <para>
       Time at which all statistics in the
       <structname>pg_stat_statements</structname> view were last reset.
      </para></entry>
     </row>

561 562 563 564 565
    </tbody>
   </tgroup>
  </table>
 </sect2>

566 567 568 569 570 571
 <sect2>
  <title>Functions</title>

  <variablelist>
   <varlistentry>
    <term>
572
     <function>pg_stat_statements_reset(userid Oid, dbid Oid, queryid bigint) returns void</function>
573 574 575
     <indexterm>
      <primary>pg_stat_statements_reset</primary>
     </indexterm>
576 577 578 579
    </term>

    <listitem>
     <para>
580 581 582 583 584 585 586
      <function>pg_stat_statements_reset</function> discards statistics
      gathered so far by <filename>pg_stat_statements</filename> corresponding
      to the specified <structfield>userid</structfield>, <structfield>dbid</structfield>
      and <structfield>queryid</structfield>.  If any of the parameters are not
      specified, the default value <literal>0</literal>(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
587 588 589 590 591
      <literal>0</literal>(invalid), it will discard all statistics.
      If all statistics in the <filename>pg_stat_statements</filename>
      view are discarded, it will also reset the statistics in the
      <structname>pg_stat_statements_info</structname> view.
      By default, this function can only be executed by superusers.
592
      Access may be granted to others using <command>GRANT</command>.
593 594 595 596
     </para>
    </listitem>
   </varlistentry>

597 598 599
   <varlistentry>
    <term>
     <function>pg_stat_statements(showtext boolean) returns setof record</function>
600 601 602 603
     <indexterm>
      <primary>pg_stat_statements</primary>
      <secondary>function</secondary>
     </indexterm>
604 605 606 607 608
    </term>

    <listitem>
     <para>
      The <structname>pg_stat_statements</structname> view is defined in
609
      terms of a function also named <function>pg_stat_statements</function>.
610 611 612 613
      It is possible for clients to call
      the <function>pg_stat_statements</function> function directly, and by
      specifying <literal>showtext := false</literal> have query text be
      omitted (that is, the <literal>OUT</literal> argument that corresponds
614
      to the view's <structfield>query</structfield> column will return nulls).  This
615 616 617 618
      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
619
      all <filename>pg_stat_statements</filename> itself does, and then retrieve
620 621 622 623 624 625
      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 <structname>pg_stat_statements</structname> data.
     </para>
    </listitem>
   </varlistentry>
626 627 628 629
  </variablelist>
 </sect2>

 <sect2>
630
  <title>Configuration Parameters</title>
631 632 633 634 635 636 637 638 639 640 641

  <variablelist>
   <varlistentry>
    <term>
     <varname>pg_stat_statements.max</varname> (<type>integer</type>)
    </term>

    <listitem>
     <para>
      <varname>pg_stat_statements.max</varname> is the maximum number of
      statements tracked by the module (i.e., the maximum number of rows
642
      in the <structname>pg_stat_statements</structname> view).  If more distinct
643
      statements than that are observed, information about the least-executed
644 645 646
      statements is discarded.  The number of times such information was
      discarded can be seen in the
      <structname>pg_stat_statements_info</structname> view.
647
      The default value is 5000.
648 649 650 651 652 653 654 655 656 657 658 659 660 661
      This parameter can only be set at server start.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term>
     <varname>pg_stat_statements.track</varname> (<type>enum</type>)
    </term>

    <listitem>
     <para>
      <varname>pg_stat_statements.track</varname> controls which statements
      are counted by the module.
662 663 664
      Specify <literal>top</literal> to track top-level statements (those issued
      directly by clients), <literal>all</literal> to also track nested statements
      (such as statements invoked within functions), or <literal>none</literal> to
665
      disable statement statistics collection.
666
      The default value is <literal>top</literal>.
667 668 669 670 671
      Only superusers can change this setting.
     </para>
    </listitem>
   </varlistentry>

672 673 674 675 676 677 678 679 680
   <varlistentry>
    <term>
     <varname>pg_stat_statements.track_utility</varname> (<type>boolean</type>)
    </term>

    <listitem>
     <para>
      <varname>pg_stat_statements.track_utility</varname> controls whether
      utility commands are tracked by the module.  Utility commands are
681 682 683
      all those other than <command>SELECT</command>, <command>INSERT</command>,
      <command>UPDATE</command> and <command>DELETE</command>.
      The default value is <literal>on</literal>.
684 685 686 687 688
      Only superusers can change this setting.
     </para>
    </listitem>
   </varlistentry>

689 690 691 692 693 694 695 696 697
   <varlistentry>
    <term>
     <varname>pg_stat_statements.track_planning</varname> (<type>boolean</type>)
    </term>

    <listitem>
     <para>
      <varname>pg_stat_statements.track_planning</varname> controls whether
      planning operations and duration are tracked by the module.
698
      Enabling this parameter may incur a noticeable performance penalty,
699 700 701
      especially when statements with identical query structure are executed
      by many concurrent connections which compete to update a small number of
      <structname>pg_stat_statements</structname> entries.
702
      The default value is <literal>off</literal>.
703 704 705 706 707
      Only superusers can change this setting.
     </para>
    </listitem>
   </varlistentry>

708 709 710 711 712 713 714 715 716
   <varlistentry>
    <term>
     <varname>pg_stat_statements.save</varname> (<type>boolean</type>)
    </term>

    <listitem>
     <para>
      <varname>pg_stat_statements.save</varname> specifies whether to
      save statement statistics across server shutdowns.
717
      If it is <literal>off</literal> then statistics are not saved at
718
      shutdown nor reloaded at server start.
719 720
      The default value is <literal>on</literal>.
      This parameter can only be set in the <filename>postgresql.conf</filename>
721 722 723 724 725 726 727
      file or on the server command line.
     </para>
    </listitem>
   </varlistentry>
  </variablelist>

  <para>
728 729
   The module requires additional shared memory proportional to
   <varname>pg_stat_statements.max</varname>.  Note that this
730
   memory is consumed whenever the module is loaded, even if
731
   <varname>pg_stat_statements.track</varname> is set to <literal>none</literal>.
732 733 734
  </para>

  <para>
735
   These parameters must be set in <filename>postgresql.conf</filename>.
736
   Typical usage might be:
737

738
<programlisting>
739 740 741
# postgresql.conf
shared_preload_libraries = 'pg_stat_statements'

742
compute_query_id = on
743 744
pg_stat_statements.max = 10000
pg_stat_statements.track = all
745 746
</programlisting>
  </para>
747 748 749
 </sect2>

 <sect2>
750
  <title>Sample Output</title>
751

752
<screen>
753
bench=# SELECT pg_stat_statements_reset();
754

755
$ pgbench -i bench
756
$ pgbench -c10 -t300 bench
757

758
bench=# \x
759
bench=# SELECT query, calls, total_exec_time, rows, 100.0 * shared_blks_hit /
760
               nullif(shared_blks_hit + shared_blks_read, 0) AS hit_percent
761
          FROM pg_stat_statements ORDER BY total_exec_time DESC LIMIT 5;
762
-[ RECORD 1 ]---+--------------------------------------------------&zwsp;------------------
763 764 765 766 767
query           | UPDATE pgbench_branches SET bbalance = bbalance + $1 WHERE bid = $2
calls           | 3000
total_exec_time | 25565.855387
rows            | 3000
hit_percent     | 100.0000000000000000
768
-[ RECORD 2 ]---+--------------------------------------------------&zwsp;------------------
769 770 771 772 773
query           | UPDATE pgbench_tellers SET tbalance = tbalance + $1 WHERE tid = $2
calls           | 3000
total_exec_time | 20756.669379
rows            | 3000
hit_percent     | 100.0000000000000000
774
-[ RECORD 3 ]---+--------------------------------------------------&zwsp;------------------
775 776 777 778 779
query           | copy pgbench_accounts from stdin
calls           | 1
total_exec_time | 291.865911
rows            | 100000
hit_percent     | 100.0000000000000000
780
-[ RECORD 4 ]---+--------------------------------------------------&zwsp;------------------
781 782 783 784 785
query           | UPDATE pgbench_accounts SET abalance = abalance + $1 WHERE aid = $2
calls           | 3000
total_exec_time | 271.232977
rows            | 3000
hit_percent     | 98.8454011741682975
786
-[ RECORD 5 ]---+--------------------------------------------------&zwsp;------------------
787 788 789 790 791
query           | alter table pgbench_accounts add primary key (aid)
calls           | 1
total_exec_time | 160.588563
rows            | 0
hit_percent     | 100.0000000000000000
792 793 794 795 796


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';

797
bench=# SELECT query, calls, total_exec_time, rows, 100.0 * shared_blks_hit /
798
               nullif(shared_blks_hit + shared_blks_read, 0) AS hit_percent
799
          FROM pg_stat_statements ORDER BY total_exec_time DESC LIMIT 5;
800
-[ RECORD 1 ]---+--------------------------------------------------&zwsp;------------------
801 802 803 804 805
query           | UPDATE pgbench_tellers SET tbalance = tbalance + $1 WHERE tid = $2
calls           | 3000
total_exec_time | 20756.669379
rows            | 3000
hit_percent     | 100.0000000000000000
806
-[ RECORD 2 ]---+--------------------------------------------------&zwsp;------------------
807 808 809 810 811
query           | copy pgbench_accounts from stdin
calls           | 1
total_exec_time | 291.865911
rows            | 100000
hit_percent     | 100.0000000000000000
812
-[ RECORD 3 ]---+--------------------------------------------------&zwsp;------------------
813 814 815 816 817
query           | UPDATE pgbench_accounts SET abalance = abalance + $1 WHERE aid = $2
calls           | 3000
total_exec_time | 271.232977
rows            | 3000
hit_percent     | 98.8454011741682975
818
-[ RECORD 4 ]---+--------------------------------------------------&zwsp;------------------
819 820 821 822 823
query           | alter table pgbench_accounts add primary key (aid)
calls           | 1
total_exec_time | 160.588563
rows            | 0
hit_percent     | 100.0000000000000000
824
-[ RECORD 5 ]---+--------------------------------------------------&zwsp;------------------
825 826 827 828 829
query           | vacuum analyze pgbench_accounts
calls           | 1
total_exec_time | 136.448116
rows            | 0
hit_percent     | 99.9201915403032721
830 831 832

bench=# SELECT pg_stat_statements_reset(0,0,0);

833
bench=# SELECT query, calls, total_exec_time, rows, 100.0 * shared_blks_hit /
834
               nullif(shared_blks_hit + shared_blks_read, 0) AS hit_percent
835
          FROM pg_stat_statements ORDER BY total_exec_time DESC LIMIT 5;
836
-[ RECORD 1 ]---+--------------------------------------------------&zwsp;---------------------------
837 838 839 840 841
query           | SELECT pg_stat_statements_reset(0,0,0)
calls           | 1
total_exec_time | 0.189497
rows            | 1
hit_percent     | 
842
-[ RECORD 2 ]---+--------------------------------------------------&zwsp;---------------------------
843 844 845 846 847 848 849
query           | SELECT query, calls, total_exec_time, rows, $1 * shared_blks_hit /          +
                |                nullif(shared_blks_hit + shared_blks_read, $2) AS hit_percent+
                |           FROM pg_stat_statements ORDER BY total_exec_time DESC LIMIT $3
calls           | 0
total_exec_time | 0
rows            | 0
hit_percent     | 
850

851
</screen>
852 853 854
 </sect2>

 <sect2>
855
  <title>Authors</title>
856 857

  <para>
858 859
   Takahiro Itagaki <email>itagaki.takahiro@oss.ntt.co.jp</email>.
   Query normalization added by Peter Geoghegan <email>peter@2ndquadrant.com</email>.
860 861 862 863
  </para>
 </sect2>

</sect1>