Commit 7466eeac authored by Tom Lane's avatar Tom Lane

Add contrib/pg_stat_statements for server-wide tracking of statement execution

statistics.

Takahiro Itagaki
parent 1efd5ff8
# $PostgreSQL: pgsql/contrib/Makefile,v 1.85 2008/11/19 02:59:28 tgl Exp $ # $PostgreSQL: pgsql/contrib/Makefile,v 1.86 2009/01/04 22:19:59 tgl Exp $
subdir = contrib subdir = contrib
top_builddir = .. top_builddir = ..
...@@ -27,6 +27,7 @@ WANTED_DIRS = \ ...@@ -27,6 +27,7 @@ WANTED_DIRS = \
pg_buffercache \ pg_buffercache \
pg_freespacemap \ pg_freespacemap \
pg_standby \ pg_standby \
pg_stat_statements \
pg_trgm \ pg_trgm \
pgbench \ pgbench \
pgcrypto \ pgcrypto \
......
...@@ -112,6 +112,10 @@ pg_standby - ...@@ -112,6 +112,10 @@ pg_standby -
Sample archive_command for warm standby operation Sample archive_command for warm standby operation
by Simon Riggs <simon@2ndquadrant.com> by Simon Riggs <simon@2ndquadrant.com>
pg_stat_statements -
Track statement execution times across a whole database cluster
by Takahiro Itagaki <itagaki.takahiro@oss.ntt.co.jp>
pg_trgm - pg_trgm -
Functions for determining the similarity of text based on trigram Functions for determining the similarity of text based on trigram
matching. matching.
......
# $PostgreSQL: pgsql/contrib/pg_stat_statements/Makefile,v 1.1 2009/01/04 22:19:59 tgl Exp $
MODULE_big = pg_stat_statements
DATA_built = pg_stat_statements.sql
DATA = uninstall_pg_stat_statements.sql
OBJS = pg_stat_statements.o
ifdef USE_PGXS
PG_CONFIG = pg_config
PGXS := $(shell $(PG_CONFIG) --pgxs)
include $(PGXS)
else
subdir = contrib/pg_stat_statements
top_builddir = ../..
include $(top_builddir)/src/Makefile.global
include $(top_srcdir)/contrib/contrib-global.mk
endif
This diff is collapsed.
/* $PostgreSQL: pgsql/contrib/pg_stat_statements/pg_stat_statements.sql.in,v 1.1 2009/01/04 22:19:59 tgl Exp $ */
-- Adjust this setting to control where the objects get created.
SET search_path = public;
-- Register functions.
CREATE FUNCTION pg_stat_statements_reset()
RETURNS void
AS 'MODULE_PATHNAME'
LANGUAGE C;
CREATE FUNCTION pg_stat_statements(
OUT userid oid,
OUT dbid oid,
OUT query text,
OUT calls int8,
OUT total_time float8,
OUT rows int8
)
RETURNS SETOF record
AS 'MODULE_PATHNAME'
LANGUAGE C;
-- Register a view on the function for ease of use.
CREATE VIEW pg_stat_statements AS
SELECT * FROM pg_stat_statements();
GRANT SELECT ON pg_stat_statements TO PUBLIC;
-- Don't want this to be available to non-superusers.
REVOKE ALL ON FUNCTION pg_stat_statements_reset() FROM PUBLIC;
/* $PostgreSQL: pgsql/contrib/pg_stat_statements/uninstall_pg_stat_statements.sql,v 1.1 2009/01/04 22:19:59 tgl Exp $ */
-- Adjust this setting to control where the objects get dropped.
SET search_path = public;
DROP VIEW pg_stat_statements;
DROP FUNCTION pg_stat_statements();
DROP FUNCTION pg_stat_statements_reset();
<!-- $PostgreSQL: pgsql/doc/src/sgml/contrib.sgml,v 1.10 2008/11/19 02:59:28 tgl Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/contrib.sgml,v 1.11 2009/01/04 22:19:59 tgl Exp $ -->
<appendix id="contrib"> <appendix id="contrib">
<title>Additional Supplied Modules</title> <title>Additional Supplied Modules</title>
...@@ -103,6 +103,7 @@ psql -d dbname -f <replaceable>SHAREDIR</>/contrib/<replaceable>module</>.sql ...@@ -103,6 +103,7 @@ psql -d dbname -f <replaceable>SHAREDIR</>/contrib/<replaceable>module</>.sql
&pgfreespacemap; &pgfreespacemap;
&pgrowlocks; &pgrowlocks;
&pgstandby; &pgstandby;
&pgstatstatements;
&pgstattuple; &pgstattuple;
&pgtrgm; &pgtrgm;
&seg; &seg;
......
<!-- $PostgreSQL: pgsql/doc/src/sgml/filelist.sgml,v 1.58 2008/11/19 02:59:28 tgl Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/filelist.sgml,v 1.59 2009/01/04 22:19:59 tgl Exp $ -->
<!entity history SYSTEM "history.sgml"> <!entity history SYSTEM "history.sgml">
<!entity info SYSTEM "info.sgml"> <!entity info SYSTEM "info.sgml">
...@@ -116,6 +116,7 @@ ...@@ -116,6 +116,7 @@
<!entity pgfreespacemap SYSTEM "pgfreespacemap.sgml"> <!entity pgfreespacemap SYSTEM "pgfreespacemap.sgml">
<!entity pgrowlocks SYSTEM "pgrowlocks.sgml"> <!entity pgrowlocks SYSTEM "pgrowlocks.sgml">
<!entity pgstandby SYSTEM "pgstandby.sgml"> <!entity pgstandby SYSTEM "pgstandby.sgml">
<!entity pgstatstatements SYSTEM "pgstatstatements.sgml">
<!entity pgstattuple SYSTEM "pgstattuple.sgml"> <!entity pgstattuple SYSTEM "pgstattuple.sgml">
<!entity pgtrgm SYSTEM "pgtrgm.sgml"> <!entity pgtrgm SYSTEM "pgtrgm.sgml">
<!entity seg SYSTEM "seg.sgml"> <!entity seg SYSTEM "seg.sgml">
......
<!-- $PostgreSQL: pgsql/doc/src/sgml/pgstatstatements.sgml,v 1.1 2009/01/04 22:19:59 tgl Exp $ -->
<sect1 id="pgstatstatements">
<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
tracking execution statistics of all SQL statements executed by a server.
</para>
<para>
The module must be loaded by adding <literal>pg_stat_statements</> to
<xref linkend="guc-shared-preload-libraries"> in
<filename>postgresql.conf</>, because it requires additional shared memory.
This means that a server restart is needed to add or remove the module.
</para>
<sect2>
<title>The <structname>pg_stat_statements</structname> view</title>
<para>
The statistics gathered by the module are made available via a system view
named <structname>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:
</para>
<table>
<title><structname>pg_stat_statements</> columns</title>
<tgroup cols="4">
<thead>
<row>
<entry>Name</entry>
<entry>Type</entry>
<entry>References</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><structfield>userid</structfield></entry>
<entry><type>oid</type></entry>
<entry><literal><link linkend="catalog-pg-authid"><structname>pg_authid</structname></link>.oid</literal></entry>
<entry>OID of user who executed the statement</entry>
</row>
<row>
<entry><structfield>dbid</structfield></entry>
<entry><type>oid</type></entry>
<entry><literal><link linkend="catalog-pg-database"><structname>pg_database</structname></link>.oid</literal></entry>
<entry>OID of database in which the statement was executed</entry>
</row>
<row>
<entry><structfield>query</structfield></entry>
<entry><type>text</type></entry>
<entry></entry>
<entry>Text of the statement (up to <xref linkend="guc-track-activity-query-size"> bytes)</entry>
</row>
<row>
<entry><structfield>calls</structfield></entry>
<entry><type>bigint</type></entry>
<entry></entry>
<entry>Number of times executed</entry>
</row>
<row>
<entry><structfield>total_time</structfield></entry>
<entry><type>double precision</type></entry>
<entry></entry>
<entry>Total time spent in the statement, in seconds</entry>
</row>
<row>
<entry><structfield>rows</structfield></entry>
<entry><type>bigint</type></entry>
<entry></entry>
<entry>Total number of rows retrieved or affected by the statement</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
This view, and the function <function>pg_stat_statements_reset</>,
are available only in databases they have been specifically installed into
by running the <filename>pg_stat_statements.sql</> install script.
However, statistics are tracked across all databases of the server
whenever the <filename>pg_stat_statements</filename> module is loaded
into the server, regardless of presence of the view.
</para>
<para>
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.
</para>
<para>
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.
</para>
</sect2>
<sect2>
<title>Functions</title>
<variablelist>
<varlistentry>
<term>
<function>pg_stat_statements_reset() returns void</function>
</term>
<listitem>
<para>
<function>pg_stat_statements_reset</function> discards all statistics
gathered so far by <filename>pg_stat_statements</>.
By default, this function can only be executed by superusers.
</para>
</listitem>
</varlistentry>
</variablelist>
</sect2>
<sect2>
<title>Configuration parameters</title>
<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
in the <structname>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.
</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.
Specify <literal>top</> to track top-level statements (those issued
directly by clients), <literal>all</> to also track nested statements
(such as statements invoked within functions), or <literal>none</> to
disable.
The default value is <literal>top</>.
Only superusers can change this setting.
</para>
</listitem>
</varlistentry>
<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.
If it is <literal>off</> then statistics are not saved at
shutdown nor reloaded at server start.
The default value is <literal>on</>.
This parameter can only be set in the <filename>postgresql.conf</>
file or on the server command line.
</para>
</listitem>
</varlistentry>
</variablelist>
<para>
The module requires additional shared memory amounting to about
<varname>pg_stat_statements.max</varname> <literal>*</>
<xref linkend="guc-track-activity-query-size"> bytes. Note that this
memory is consumed whenever the module is loaded, even if
<varname>pg_stat_statements.track</> is set to <literal>none</>.
</para>
<para>
In order to set any of these parameters in your
<filename>postgresql.conf</> file,
you will need to add <literal>pg_stat_statements</> to
<xref linkend="guc-custom-variable-classes">. Typical usage might be:
</para>
<programlisting>
# postgresql.conf
shared_preload_libraries = 'pg_stat_statements'
custom_variable_classes = 'pg_stat_statements'
pg_stat_statements.max = 10000
pg_stat_statements.track = all
</programlisting>
</sect2>
<sect2>
<title>Sample output</title>
<programlisting>
$ 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
</programlisting>
</sect2>
<sect2>
<title>Author</title>
<para>
Takahiro Itagaki <email>itagaki.takahiro@oss.ntt.co.jp</email>
</para>
</sect2>
</sect1>
...@@ -37,7 +37,7 @@ ...@@ -37,7 +37,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/postmaster/postmaster.c,v 1.569 2009/01/03 17:08:38 tgl Exp $ * $PostgreSQL: pgsql/src/backend/postmaster/postmaster.c,v 1.570 2009/01/04 22:19:59 tgl Exp $
* *
* NOTES * NOTES
* *
...@@ -2731,7 +2731,7 @@ PostmasterStateMachine(void) ...@@ -2731,7 +2731,7 @@ PostmasterStateMachine(void)
ereport(LOG, ereport(LOG,
(errmsg("all server processes terminated; reinitializing"))); (errmsg("all server processes terminated; reinitializing")));
shmem_exit(0); shmem_exit(1);
reset_shared(PostPortNumber); reset_shared(PostPortNumber);
StartupPID = StartupDataBase(); StartupPID = StartupDataBase();
......
...@@ -5,7 +5,7 @@ ...@@ -5,7 +5,7 @@
* *
* Copyright (c) 2001-2009, PostgreSQL Global Development Group * Copyright (c) 2001-2009, PostgreSQL Global Development Group
* *
* $PostgreSQL: pgsql/src/include/pgstat.h,v 1.81 2009/01/01 17:23:55 momjian Exp $ * $PostgreSQL: pgsql/src/include/pgstat.h,v 1.82 2009/01/04 22:19:59 tgl Exp $
* ---------- * ----------
*/ */
#ifndef PGSTAT_H #ifndef PGSTAT_H
...@@ -592,7 +592,7 @@ typedef struct PgStat_FunctionCallUsage ...@@ -592,7 +592,7 @@ typedef struct PgStat_FunctionCallUsage
extern bool pgstat_track_activities; extern bool pgstat_track_activities;
extern bool pgstat_track_counts; extern bool pgstat_track_counts;
extern int pgstat_track_functions; extern int pgstat_track_functions;
extern int pgstat_track_activity_query_size; extern PGDLLIMPORT int pgstat_track_activity_query_size;
extern char *pgstat_stat_tmpname; extern char *pgstat_stat_tmpname;
extern char *pgstat_stat_filename; extern char *pgstat_stat_filename;
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment