1
0
mirror of https://github.com/postgres/postgres.git synced 2025-09-03 15:22:11 +03:00
Files
postgres/doc/src/sgml/pgstattuple.sgml
Tom Lane 48e6c943e5 Fix multiple bugs in contrib/pgstattuple's pgstatindex() function.
Dead or half-dead index leaf pages were incorrectly reported as live, as a
consequence of a code rearrangement I made (during a moment of severe brain
fade, evidently) in commit d287818eb5.

The index metapage was not counted in index_size, causing that result to
not agree with the actual index size on-disk.

Index root pages were not counted in internal_pages, which is inconsistent
compared to the case of a root that's also a leaf (one-page index), where
the root would be counted in leaf_pages.  Aside from that inconsistency,
this could lead to additional transient discrepancies between the reported
page counts and index_size, since it's possible for pgstatindex's scan to
see zero or multiple pages marked as BTP_ROOT, if the root moves due to
a split during the scan.  With these fixes, index_size will always be
exactly one page more than the sum of the displayed page counts.

Also, the index_size result was incorrectly documented as being measured in
pages; it's always been measured in bytes.  (While fixing that, I couldn't
resist doing some small additional wordsmithing on the pgstattuple docs.)

Including the metapage causes the reported index_size to not be zero for
an empty index.  To preserve the desired property that the pgstattuple
regression test results are platform-independent (ie, BLCKSZ configuration
independent), scale the index_size result in the regression tests.

The documentation issue was reported by Otsuka Kenji, and the inconsistent
root page counting by Peter Geoghegan; the other problems noted by me.
Back-patch to all supported branches, because this has been broken for
a long time.
2016-02-18 15:40:35 -05:00

514 lines
15 KiB
Plaintext

<!-- doc/src/sgml/pgstattuple.sgml -->
<sect1 id="pgstattuple" xreflabel="pgstattuple">
<title>pgstattuple</title>
<indexterm zone="pgstattuple">
<primary>pgstattuple</primary>
</indexterm>
<para>
The <filename>pgstattuple</filename> module provides various functions to
obtain tuple-level statistics.
</para>
<sect2>
<title>Functions</title>
<variablelist>
<varlistentry>
<term>
<indexterm>
<primary>pgstattuple</primary>
</indexterm>
<function>pgstattuple(regclass) returns record</>
</term>
<listitem>
<para>
<function>pgstattuple</function> returns a relation's physical length,
percentage of <quote>dead</> tuples, and other info. This may help users
to determine whether vacuum is necessary or not. The argument is the
target relation's name (optionally schema-qualified) or OID.
For example:
<programlisting>
test=&gt; SELECT * FROM pgstattuple('pg_catalog.pg_proc');
-[ RECORD 1 ]------+-------
table_len | 458752
tuple_count | 1470
tuple_len | 438896
tuple_percent | 95.67
dead_tuple_count | 11
dead_tuple_len | 3157
dead_tuple_percent | 0.69
free_space | 8932
free_percent | 1.95
</programlisting>
The output columns are described in <xref linkend="pgstattuple-columns">.
</para>
<table id="pgstattuple-columns">
<title><function>pgstattuple</function> Output Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Column</entry>
<entry>Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><structfield>table_len</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Physical relation length in bytes</entry>
</row>
<row>
<entry><structfield>tuple_count</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Number of live tuples</entry>
</row>
<row>
<entry><structfield>tuple_len</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Total length of live tuples in bytes</entry>
</row>
<row>
<entry><structfield>tuple_percent</structfield></entry>
<entry><type>float8</type></entry>
<entry>Percentage of live tuples</entry>
</row>
<row>
<entry><structfield>dead_tuple_count</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Number of dead tuples</entry>
</row>
<row>
<entry><structfield>dead_tuple_len</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Total length of dead tuples in bytes</entry>
</row>
<row>
<entry><structfield>dead_tuple_percent</structfield></entry>
<entry><type>float8</type></entry>
<entry>Percentage of dead tuples</entry>
</row>
<row>
<entry><structfield>free_space</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Total free space in bytes</entry>
</row>
<row>
<entry><structfield>free_percent</structfield></entry>
<entry><type>float8</type></entry>
<entry>Percentage of free space</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
<function>pgstattuple</function> acquires only a read lock on the
relation. So the results do not reflect an instantaneous snapshot;
concurrent updates will affect them.
</para>
<para>
<function>pgstattuple</function> judges a tuple is <quote>dead</> if
<function>HeapTupleSatisfiesDirty</> returns false.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<function>pgstattuple(text) returns record</>
</term>
<listitem>
<para>
This is the same as <function>pgstattuple(regclass)</function>, except
that the target relation is specified as TEXT. This function is kept
because of backward-compatibility so far, and will be deprecated in
some future release.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<indexterm>
<primary>pgstatindex</primary>
</indexterm>
<function>pgstatindex(regclass) returns record</>
</term>
<listitem>
<para>
<function>pgstatindex</function> returns a record showing information
about a B-tree index. For example:
<programlisting>
test=&gt; SELECT * FROM pgstatindex('pg_cast_oid_index');
-[ RECORD 1 ]------+------
version | 2
tree_level | 0
index_size | 16384
root_block_no | 1
internal_pages | 0
leaf_pages | 1
empty_pages | 0
deleted_pages | 0
avg_leaf_density | 54.27
leaf_fragmentation | 0
</programlisting>
</para>
<para>
The output columns are:
<informaltable>
<tgroup cols="3">
<thead>
<row>
<entry>Column</entry>
<entry>Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><structfield>version</structfield></entry>
<entry><type>integer</type></entry>
<entry>B-tree version number</entry>
</row>
<row>
<entry><structfield>tree_level</structfield></entry>
<entry><type>integer</type></entry>
<entry>Tree level of the root page</entry>
</row>
<row>
<entry><structfield>index_size</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Total index size in bytes</entry>
</row>
<row>
<entry><structfield>root_block_no</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Location of root page (zero if none)</entry>
</row>
<row>
<entry><structfield>internal_pages</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Number of <quote>internal</> (upper-level) pages</entry>
</row>
<row>
<entry><structfield>leaf_pages</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Number of leaf pages</entry>
</row>
<row>
<entry><structfield>empty_pages</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Number of empty pages</entry>
</row>
<row>
<entry><structfield>deleted_pages</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Number of deleted pages</entry>
</row>
<row>
<entry><structfield>avg_leaf_density</structfield></entry>
<entry><type>float8</type></entry>
<entry>Average density of leaf pages</entry>
</row>
<row>
<entry><structfield>leaf_fragmentation</structfield></entry>
<entry><type>float8</type></entry>
<entry>Leaf page fragmentation</entry>
</row>
</tbody>
</tgroup>
</informaltable>
</para>
<para>
The reported <literal>index_size</> will normally correspond to one more
page than is accounted for by <literal>internal_pages + leaf_pages +
empty_pages + deleted_pages</literal>, because it also includes the
index's metapage.
</para>
<para>
As with <function>pgstattuple</>, the results are accumulated
page-by-page, and should not be expected to represent an
instantaneous snapshot of the whole index.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<function>pgstatindex(text) returns record</>
</term>
<listitem>
<para>
This is the same as <function>pgstatindex(regclass)</function>, except
that the target index is specified as TEXT. This function is kept
because of backward-compatibility so far, and will be deprecated in
some future release.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<indexterm>
<primary>pgstatginindex</primary>
</indexterm>
<function>pgstatginindex(regclass) returns record</>
</term>
<listitem>
<para>
<function>pgstatginindex</function> returns a record showing information
about a GIN index. For example:
<programlisting>
test=&gt; SELECT * FROM pgstatginindex('test_gin_index');
-[ RECORD 1 ]--+--
version | 1
pending_pages | 0
pending_tuples | 0
</programlisting>
</para>
<para>
The output columns are:
<informaltable>
<tgroup cols="3">
<thead>
<row>
<entry>Column</entry>
<entry>Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><structfield>version</structfield></entry>
<entry><type>integer</type></entry>
<entry>GIN version number</entry>
</row>
<row>
<entry><structfield>pending_pages</structfield></entry>
<entry><type>integer</type></entry>
<entry>Number of pages in the pending list</entry>
</row>
<row>
<entry><structfield>pending_tuples</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Number of tuples in the pending list</entry>
</row>
</tbody>
</tgroup>
</informaltable>
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<indexterm>
<primary>pg_relpages</primary>
</indexterm>
<function>pg_relpages(regclass) returns bigint</>
</term>
<listitem>
<para>
<function>pg_relpages</function> returns the number of pages in the
relation.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<function>pg_relpages(text) returns bigint</>
</term>
<listitem>
<para>
This is the same as <function>pg_relpages(regclass)</function>, except
that the target relation is specified as TEXT. This function is kept
because of backward-compatibility so far, and will be deprecated in
some future release.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<indexterm>
<primary>pgstattuple_approx</primary>
</indexterm>
<function>pgstattuple_approx(regclass) returns record</>
</term>
<listitem>
<para>
<function>pgstattuple_approx</function> is a faster alternative to
<function>pgstattuple</function> that returns approximate results.
The argument is the target relation's name or OID.
For example:
<programlisting>
test=&gt; SELECT * FROM pgstattuple_approx('pg_catalog.pg_proc'::regclass);
-[ RECORD 1 ]--------+-------
table_len | 573440
scanned_percent | 2
approx_tuple_count | 2740
approx_tuple_len | 561210
approx_tuple_percent | 97.87
dead_tuple_count | 0
dead_tuple_len | 0
dead_tuple_percent | 0
approx_free_space | 11996
approx_free_percent | 2.09
</programlisting>
The output columns are described in <xref linkend="pgstatapprox-columns">.
</para>
<para>
Whereas <function>pgstattuple</function> always performs a
full-table scan and returns an exact count of live and dead tuples
(and their sizes) and free space, <function>pgstattuple_approx</function>
tries to avoid the full-table scan and returns exact dead tuple
statistics along with an approximation of the number and
size of live tuples and free space.
</para>
<para>
It does this by skipping pages that have only visible tuples
according to the visibility map (if a page has the corresponding VM
bit set, then it is assumed to contain no dead tuples). For such
pages, it derives the free space value from the free space map, and
assumes that the rest of the space on the page is taken up by live
tuples.
</para>
<para>
For pages that cannot be skipped, it scans each tuple, recording its
presence and size in the appropriate counters, and adding up the
free space on the page. At the end, it estimates the total number of
live tuples based on the number of pages and tuples scanned (in the
same way that VACUUM estimates pg_class.reltuples).
</para>
<table id="pgstatapprox-columns">
<title><function>pgstattuple_approx</function> Output Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Column</entry>
<entry>Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><structfield>table_len</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Physical relation length in bytes (exact)</entry>
</row>
<row>
<entry><structfield>scanned_percent</structfield></entry>
<entry><type>float8</type></entry>
<entry>Percentage of table scanned</entry>
</row>
<row>
<entry><structfield>approx_tuple_count</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Number of live tuples (estimated)</entry>
</row>
<row>
<entry><structfield>approx_tuple_len</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Total length of live tuples in bytes (estimated)</entry>
</row>
<row>
<entry><structfield>approx_tuple_percent</structfield></entry>
<entry><type>float8</type></entry>
<entry>Percentage of live tuples</entry>
</row>
<row>
<entry><structfield>dead_tuple_count</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Number of dead tuples (exact)</entry>
</row>
<row>
<entry><structfield>dead_tuple_len</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Total length of dead tuples in bytes (exact)</entry>
</row>
<row>
<entry><structfield>dead_tuple_percent</structfield></entry>
<entry><type>float8</type></entry>
<entry>Percentage of dead tuples</entry>
</row>
<row>
<entry><structfield>approx_free_space</structfield></entry>
<entry><type>bigint</type></entry>
<entry>Total free space in bytes (estimated)</entry>
</row>
<row>
<entry><structfield>approx_free_percent</structfield></entry>
<entry><type>float8</type></entry>
<entry>Percentage of free space</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
In the above output, the free space figures may not match the
<function>pgstattuple</function> output exactly, because the free
space map gives us an exact figure, but is not guaranteed to be
accurate to the byte.
</para>
</listitem>
</varlistentry>
</variablelist>
</sect2>
<sect2>
<title>Authors</title>
<para>
Tatsuo Ishii, Satoshi Nagayasu and Abhijit Menon-Sen
</para>
</sect2>
</sect1>