1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!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.33. pgstattuple — obtain tuple-level statistics</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 Vsnapshot" /><link rel="prev" href="pgstatstatements.html" title="F.32. pg_stat_statements — track statistics of SQL planning and execution" /><link rel="next" href="pgsurgery.html" title="F.34. pg_surgery — perform low-level surgery on relation data" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">F.33. pgstattuple — obtain tuple-level statistics</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="pgstatstatements.html" title="F.32. pg_stat_statements — track statistics of SQL planning and execution">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="contrib.html" title="Appendix F. Additional Supplied Modules and Extensions">Up</a></td><th width="60%" align="center">Appendix F. Additional Supplied Modules and Extensions</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="pgsurgery.html" title="F.34. pg_surgery — perform low-level surgery on relation data">Next</a></td></tr></table><hr /></div><div class="sect1" id="PGSTATTUPLE"><div class="titlepage"><div><div><h2 class="title" style="clear: both">F.33. pgstattuple — obtain tuple-level statistics <a href="#PGSTATTUPLE" class="id_link">#</a></h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="pgstattuple.html#PGSTATTUPLE-FUNCS">F.33.1. Functions</a></span></dt><dt><span class="sect2"><a href="pgstattuple.html#PGSTATTUPLE-AUTHORS">F.33.2. Authors</a></span></dt></dl></div><a id="id-1.11.7.43.2" class="indexterm"></a><p>
3 The <code class="filename">pgstattuple</code> module provides various functions to
4 obtain tuple-level statistics.
6 Because these functions return detailed page-level information, access is
7 restricted by default. By default, only the
8 role <code class="literal">pg_stat_scan_tables</code> has <code class="literal">EXECUTE</code>
9 privilege. Superusers of course bypass this restriction. After the
10 extension has been installed, users may issue <code class="command">GRANT</code>
11 commands to change the privileges on the functions to allow others to
12 execute them. However, it might be preferable to add those users to
13 the <code class="literal">pg_stat_scan_tables</code> role instead.
14 </p><div class="sect2" id="PGSTATTUPLE-FUNCS"><div class="titlepage"><div><div><h3 class="title">F.33.1. Functions <a href="#PGSTATTUPLE-FUNCS" class="id_link">#</a></h3></div></div></div><div class="variablelist"><dl class="variablelist"><dt><span class="term">
15 <a id="id-1.11.7.43.5.2.1.1.1" class="indexterm"></a>
16 <code class="function">pgstattuple(regclass) returns record</code>
18 <code class="function">pgstattuple</code> returns a relation's physical length,
19 percentage of <span class="quote">“<span class="quote">dead</span>”</span> tuples, and other info. This may help users
20 to determine whether vacuum is necessary or not. The argument is the
21 target relation's name (optionally schema-qualified) or OID.
23 </p><pre class="programlisting">
24 test=> SELECT * FROM pgstattuple('pg_catalog.pg_proc');
25 -[ RECORD 1 ]------+-------
32 dead_tuple_percent | 0.69
36 The output columns are described in <a class="xref" href="pgstattuple.html#PGSTATTUPLE-COLUMNS" title="Table F.24. pgstattuple Output Columns">Table F.24</a>.
37 </p><div class="table" id="PGSTATTUPLE-COLUMNS"><p class="title"><strong>Table F.24. <code class="function">pgstattuple</code> Output Columns</strong></p><div class="table-contents"><table class="table" summary="pgstattuple Output Columns" border="1"><colgroup><col /><col /><col /></colgroup><thead><tr><th>Column</th><th>Type</th><th>Description</th></tr></thead><tbody><tr><td><code class="structfield">table_len</code></td><td><code class="type">bigint</code></td><td>Physical relation length in bytes</td></tr><tr><td><code class="structfield">tuple_count</code></td><td><code class="type">bigint</code></td><td>Number of live tuples</td></tr><tr><td><code class="structfield">tuple_len</code></td><td><code class="type">bigint</code></td><td>Total length of live tuples in bytes</td></tr><tr><td><code class="structfield">tuple_percent</code></td><td><code class="type">float8</code></td><td>Percentage of live tuples</td></tr><tr><td><code class="structfield">dead_tuple_count</code></td><td><code class="type">bigint</code></td><td>Number of dead tuples</td></tr><tr><td><code class="structfield">dead_tuple_len</code></td><td><code class="type">bigint</code></td><td>Total length of dead tuples in bytes</td></tr><tr><td><code class="structfield">dead_tuple_percent</code></td><td><code class="type">float8</code></td><td>Percentage of dead tuples</td></tr><tr><td><code class="structfield">free_space</code></td><td><code class="type">bigint</code></td><td>Total free space in bytes</td></tr><tr><td><code class="structfield">free_percent</code></td><td><code class="type">float8</code></td><td>Percentage of free space</td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
38 The <code class="literal">table_len</code> will always be greater than the sum
39 of the <code class="literal">tuple_len</code>, <code class="literal">dead_tuple_len</code>
40 and <code class="literal">free_space</code>. The difference is accounted for by
41 fixed page overhead, the per-page table of pointers to tuples, and
42 padding to ensure that tuples are correctly aligned.
44 <code class="function">pgstattuple</code> acquires only a read lock on the
45 relation. So the results do not reflect an instantaneous snapshot;
46 concurrent updates will affect them.
48 <code class="function">pgstattuple</code> judges a tuple is <span class="quote">“<span class="quote">dead</span>”</span> if
49 <code class="function">HeapTupleSatisfiesDirty</code> returns false.
50 </p></dd><dt><span class="term">
51 <code class="function">pgstattuple(text) returns record</code>
53 This is the same as <code class="function">pgstattuple(regclass)</code>, except
54 that the target relation is specified as TEXT. This function is kept
55 because of backward-compatibility so far, and will be deprecated in
57 </p></dd><dt><span class="term">
58 <a id="id-1.11.7.43.5.2.3.1.1" class="indexterm"></a>
59 <code class="function">pgstatindex(regclass) returns record</code>
61 <code class="function">pgstatindex</code> returns a record showing information
62 about a B-tree index. For example:
63 </p><pre class="programlisting">
64 test=> SELECT * FROM pgstatindex('pg_cast_oid_index');
65 -[ RECORD 1 ]------+------
74 avg_leaf_density | 54.27
75 leaf_fragmentation | 0
78 The output columns are:
80 </p><div class="informaltable"><table class="informaltable" border="1"><colgroup><col /><col /><col /></colgroup><thead><tr><th>Column</th><th>Type</th><th>Description</th></tr></thead><tbody><tr><td><code class="structfield">version</code></td><td><code class="type">integer</code></td><td>B-tree version number</td></tr><tr><td><code class="structfield">tree_level</code></td><td><code class="type">integer</code></td><td>Tree level of the root page</td></tr><tr><td><code class="structfield">index_size</code></td><td><code class="type">bigint</code></td><td>Total index size in bytes</td></tr><tr><td><code class="structfield">root_block_no</code></td><td><code class="type">bigint</code></td><td>Location of root page (zero if none)</td></tr><tr><td><code class="structfield">internal_pages</code></td><td><code class="type">bigint</code></td><td>Number of <span class="quote">“<span class="quote">internal</span>”</span> (upper-level) pages</td></tr><tr><td><code class="structfield">leaf_pages</code></td><td><code class="type">bigint</code></td><td>Number of leaf pages</td></tr><tr><td><code class="structfield">empty_pages</code></td><td><code class="type">bigint</code></td><td>Number of empty pages</td></tr><tr><td><code class="structfield">deleted_pages</code></td><td><code class="type">bigint</code></td><td>Number of deleted pages</td></tr><tr><td><code class="structfield">avg_leaf_density</code></td><td><code class="type">float8</code></td><td>Average density of leaf pages</td></tr><tr><td><code class="structfield">leaf_fragmentation</code></td><td><code class="type">float8</code></td><td>Leaf page fragmentation</td></tr></tbody></table></div><p>
82 The reported <code class="literal">index_size</code> will normally correspond to one more
83 page than is accounted for by <code class="literal">internal_pages + leaf_pages +
84 empty_pages + deleted_pages</code>, because it also includes the
87 As with <code class="function">pgstattuple</code>, the results are accumulated
88 page-by-page, and should not be expected to represent an
89 instantaneous snapshot of the whole index.
90 </p></dd><dt><span class="term">
91 <code class="function">pgstatindex(text) returns record</code>
93 This is the same as <code class="function">pgstatindex(regclass)</code>, except
94 that the target index is specified as TEXT. This function is kept
95 because of backward-compatibility so far, and will be deprecated in
97 </p></dd><dt><span class="term">
98 <a id="id-1.11.7.43.5.2.5.1.1" class="indexterm"></a>
99 <code class="function">pgstatginindex(regclass) returns record</code>
101 <code class="function">pgstatginindex</code> returns a record showing information
102 about a GIN index. For example:
103 </p><pre class="programlisting">
104 test=> SELECT * FROM pgstatginindex('test_gin_index');
111 The output columns are:
113 </p><div class="informaltable"><table class="informaltable" border="1"><colgroup><col /><col /><col /></colgroup><thead><tr><th>Column</th><th>Type</th><th>Description</th></tr></thead><tbody><tr><td><code class="structfield">version</code></td><td><code class="type">integer</code></td><td>GIN version number</td></tr><tr><td><code class="structfield">pending_pages</code></td><td><code class="type">integer</code></td><td>Number of pages in the pending list</td></tr><tr><td><code class="structfield">pending_tuples</code></td><td><code class="type">bigint</code></td><td>Number of tuples in the pending list</td></tr></tbody></table></div><p>
114 </p></dd><dt><span class="term">
115 <a id="id-1.11.7.43.5.2.6.1.1" class="indexterm"></a>
116 <code class="function">pgstathashindex(regclass) returns record</code>
118 <code class="function">pgstathashindex</code> returns a record showing information
119 about a HASH index. For example:
120 </p><pre class="programlisting">
121 test=> select * from pgstathashindex('con_hash_index');
122 -[ RECORD 1 ]--+-----------------
128 live_items | 10204006
130 free_percent | 61.8005949100872
133 The output columns are:
135 </p><div class="informaltable"><table class="informaltable" border="1"><colgroup><col /><col /><col /></colgroup><thead><tr><th>Column</th><th>Type</th><th>Description</th></tr></thead><tbody><tr><td><code class="structfield">version</code></td><td><code class="type">integer</code></td><td>HASH version number</td></tr><tr><td><code class="structfield">bucket_pages</code></td><td><code class="type">bigint</code></td><td>Number of bucket pages</td></tr><tr><td><code class="structfield">overflow_pages</code></td><td><code class="type">bigint</code></td><td>Number of overflow pages</td></tr><tr><td><code class="structfield">bitmap_pages</code></td><td><code class="type">bigint</code></td><td>Number of bitmap pages</td></tr><tr><td><code class="structfield">unused_pages</code></td><td><code class="type">bigint</code></td><td>Number of unused pages</td></tr><tr><td><code class="structfield">live_items</code></td><td><code class="type">bigint</code></td><td>Number of live tuples</td></tr><tr><td><code class="structfield">dead_tuples</code></td><td><code class="type">bigint</code></td><td>Number of dead tuples</td></tr><tr><td><code class="structfield">free_percent</code></td><td><code class="type">float</code></td><td>Percentage of free space</td></tr></tbody></table></div><p>
136 </p></dd><dt><span class="term">
137 <a id="id-1.11.7.43.5.2.7.1.1" class="indexterm"></a>
138 <code class="function">pg_relpages(regclass) returns bigint</code>
140 <code class="function">pg_relpages</code> returns the number of pages in the
142 </p></dd><dt><span class="term">
143 <code class="function">pg_relpages(text) returns bigint</code>
145 This is the same as <code class="function">pg_relpages(regclass)</code>, except
146 that the target relation is specified as TEXT. This function is kept
147 because of backward-compatibility so far, and will be deprecated in
149 </p></dd><dt><span class="term">
150 <a id="id-1.11.7.43.5.2.9.1.1" class="indexterm"></a>
151 <code class="function">pgstattuple_approx(regclass) returns record</code>
153 <code class="function">pgstattuple_approx</code> is a faster alternative to
154 <code class="function">pgstattuple</code> that returns approximate results.
155 The argument is the target relation's name or OID.
157 </p><pre class="programlisting">
158 test=> SELECT * FROM pgstattuple_approx('pg_catalog.pg_proc'::regclass);
159 -[ RECORD 1 ]--------+-------
162 approx_tuple_count | 2740
163 approx_tuple_len | 561210
164 approx_tuple_percent | 97.87
167 dead_tuple_percent | 0
168 approx_free_space | 11996
169 approx_free_percent | 2.09
171 The output columns are described in <a class="xref" href="pgstattuple.html#PGSTATAPPROX-COLUMNS" title="Table F.25. pgstattuple_approx Output Columns">Table F.25</a>.
173 Whereas <code class="function">pgstattuple</code> always performs a
174 full-table scan and returns an exact count of live and dead tuples
175 (and their sizes) and free space, <code class="function">pgstattuple_approx</code>
176 tries to avoid the full-table scan and returns exact dead tuple
177 statistics along with an approximation of the number and
178 size of live tuples and free space.
180 It does this by skipping pages that have only visible tuples
181 according to the visibility map (if a page has the corresponding VM
182 bit set, then it is assumed to contain no dead tuples). For such
183 pages, it derives the free space value from the free space map, and
184 assumes that the rest of the space on the page is taken up by live
187 For pages that cannot be skipped, it scans each tuple, recording its
188 presence and size in the appropriate counters, and adding up the
189 free space on the page. At the end, it estimates the total number of
190 live tuples based on the number of pages and tuples scanned (in the
191 same way that VACUUM estimates pg_class.reltuples).
192 </p><div class="table" id="PGSTATAPPROX-COLUMNS"><p class="title"><strong>Table F.25. <code class="function">pgstattuple_approx</code> Output Columns</strong></p><div class="table-contents"><table class="table" summary="pgstattuple_approx Output Columns" border="1"><colgroup><col /><col /><col /></colgroup><thead><tr><th>Column</th><th>Type</th><th>Description</th></tr></thead><tbody><tr><td><code class="structfield">table_len</code></td><td><code class="type">bigint</code></td><td>Physical relation length in bytes (exact)</td></tr><tr><td><code class="structfield">scanned_percent</code></td><td><code class="type">float8</code></td><td>Percentage of table scanned</td></tr><tr><td><code class="structfield">approx_tuple_count</code></td><td><code class="type">bigint</code></td><td>Number of live tuples (estimated)</td></tr><tr><td><code class="structfield">approx_tuple_len</code></td><td><code class="type">bigint</code></td><td>Total length of live tuples in bytes (estimated)</td></tr><tr><td><code class="structfield">approx_tuple_percent</code></td><td><code class="type">float8</code></td><td>Percentage of live tuples</td></tr><tr><td><code class="structfield">dead_tuple_count</code></td><td><code class="type">bigint</code></td><td>Number of dead tuples (exact)</td></tr><tr><td><code class="structfield">dead_tuple_len</code></td><td><code class="type">bigint</code></td><td>Total length of dead tuples in bytes (exact)</td></tr><tr><td><code class="structfield">dead_tuple_percent</code></td><td><code class="type">float8</code></td><td>Percentage of dead tuples</td></tr><tr><td><code class="structfield">approx_free_space</code></td><td><code class="type">bigint</code></td><td>Total free space in bytes (estimated)</td></tr><tr><td><code class="structfield">approx_free_percent</code></td><td><code class="type">float8</code></td><td>Percentage of free space</td></tr></tbody></table></div></div><br class="table-break" /><p>
193 In the above output, the free space figures may not match the
194 <code class="function">pgstattuple</code> output exactly, because the free
195 space map gives us an exact figure, but is not guaranteed to be
196 accurate to the byte.
197 </p></dd></dl></div></div><div class="sect2" id="PGSTATTUPLE-AUTHORS"><div class="titlepage"><div><div><h3 class="title">F.33.2. Authors <a href="#PGSTATTUPLE-AUTHORS" class="id_link">#</a></h3></div></div></div><p>
198 Tatsuo Ishii, Satoshi Nagayasu and Abhijit Menon-Sen
199 </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="pgstatstatements.html" title="F.32. pg_stat_statements — track statistics of SQL planning and execution">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="contrib.html" title="Appendix F. Additional Supplied Modules and Extensions">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="pgsurgery.html" title="F.34. pg_surgery — perform low-level surgery on relation data">Next</a></td></tr><tr><td width="40%" align="left" valign="top">F.32. pg_stat_statements — track statistics of SQL planning and execution </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> F.34. pg_surgery — perform low-level surgery on relation data</td></tr></table></div></body></html>