Skip to content
Snippets Groups Projects
vacuum.sgml 9.10 KiB
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/vacuum.sgml,v 1.25 2002/04/23 02:07:16 tgl Exp $
PostgreSQL documentation
-->

<refentry id="SQL-VACUUM">
 <refmeta>
  <refentrytitle id="sql-vacuum-title">VACUUM</refentrytitle>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>
 <refnamediv>
  <refname>
   VACUUM
  </refname>
  <refpurpose>
   garbage-collect and optionally analyze a database
  </refpurpose>
 </refnamediv>
 <refsynopsisdiv>
  <refsynopsisdivinfo>
   <date>2001-08-26</date>
  </refsynopsisdivinfo>
  <synopsis>
VACUUM [ FULL ] [ FREEZE ] [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> ]
VACUUM [ FULL ] [ FREEZE ] [ VERBOSE ] ANALYZE [ <replaceable class="PARAMETER">table</replaceable> [ (<replaceable class="PARAMETER">column</replaceable> [, ...] ) ] ]
  </synopsis>

  <refsect2 id="R2-SQL-VACUUM-1">
   <refsect2info>
    <date>2001-07-10</date>
   </refsect2info>
   <title>
    Inputs
   </title>

   <para>
    <variablelist>
     <varlistentry>
      <term>FULL</term>
      <listitem>
       <para>
        Selects <quote>full</quote> vacuum, which may reclaim more space,
	but takes much longer and exclusively locks the table.
       </para>
      </listitem>
     </varlistentry>
     <varlistentry>
      <term>FREEZE</term>
      <listitem>
       <para>
        Selects aggressive <quote>freezing</quote> of tuples.
       </para>
      </listitem>
     </varlistentry>
     <varlistentry>
      <term>VERBOSE</term>
      <listitem>
       <para>
	Prints a detailed vacuum activity report for each table.
       </para>
      </listitem>
     </varlistentry>
     <varlistentry>
      <term>ANALYZE</term>
      <listitem>
       <para>
	Updates statistics used by the optimizer to
	determine the most efficient way to execute a query.
       </para>
      </listitem>
     </varlistentry>
     <varlistentry>
      <term><replaceable class="PARAMETER">table</replaceable></term>
      <listitem>
       <para>
	The name (optionally schema-qualified) of a specific table to
	vacuum. Defaults to all tables in the current database.
       </para>
      </listitem>
     </varlistentry>
     <varlistentry>
      <term><replaceable class="PARAMETER">column</replaceable></term>
      <listitem>
       <para>
	The name of a specific column to analyze. Defaults to all columns.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>
  </refsect2>

  <refsect2 id="R2-SQL-VACUUM-2">
   <refsect2info>
    <date>1998-10-04</date>
   </refsect2info>
   <title>
    Outputs
   </title>
   <para>

    <variablelist>
     <varlistentry>
      <term><computeroutput>
<returnvalue>VACUUM</returnvalue>
       </computeroutput></term>
      <listitem>
       <para>
	The command is complete.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><computeroutput>
INFO:  --Relation <replaceable class="PARAMETER">table</replaceable>--
       </computeroutput></term>
      <listitem>
       <para>
	The report header for <replaceable class="PARAMETER">table</replaceable>.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><computeroutput>
INFO:  Pages 98: Changed 25, Reapped 74, Empty 0, New 0;
         Tup 1000: Vac 3000, Crash 0, UnUsed 0, MinLen 188, MaxLen 188;
         Re-using: Free/Avail. Space 586952/586952; EndEmpty/Avail. Pages 0/74.
         Elapsed 0/0 sec.
       </computeroutput></term>
      <listitem>
       <para>
	The analysis for <replaceable class="PARAMETER">table</replaceable> itself.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><computeroutput>
INFO:  Index <replaceable class="PARAMETER">index</replaceable>: Pages 28;
         Tuples 1000: Deleted 3000. Elapsed 0/0 sec.
       </computeroutput></term>
      <listitem>
       <para>
	The analysis for an index on the target table.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>
  </refsect2>
 </refsynopsisdiv>

 <refsect1 id="R1-SQL-VACUUM-1">
  <refsect1info>
   <date>2001-07-10</date>
  </refsect1info>
  <title>
   Description
  </title>
  <para>
   <command>VACUUM</command> reclaims storage occupied by deleted tuples.
   In normal <productname>PostgreSQL</productname> operation, tuples that
   are DELETEd or obsoleted by UPDATE are not physically removed from
   their table; they remain present until a <command>VACUUM</command> is
   done.  Therefore it's necessary to do <command>VACUUM</command>
   periodically, especially on frequently-updated tables.
  </para>

  <para>
   With no parameter, <command>VACUUM</command> processes every table in the
   current database.  With a parameter, <command>VACUUM</command> processes
   only that table.
  </para>

  <para>
   <command>VACUUM ANALYZE</command> performs a <command>VACUUM</command>
   and then an <command>ANALYZE</command> for each selected table.  This
   is a handy combination form for routine maintenance scripts.  See
   <xref linkend="sql-analyze" endterm="sql-analyze-title">
   for more details about its processing.
  </para>

  <para>
   Plain <command>VACUUM</command> (without <literal>FULL</>) simply reclaims
   space and makes it
   available for re-use.  This form of the command can operate in parallel
   with normal reading and writing of the table.  <command>VACUUM
   FULL</command> does more extensive processing, including moving of tuples
   across blocks to try to compact the table to the minimum number of disk
   blocks.  This form is much slower and requires an exclusive lock on each
   table while it is being processed.
  </para>

  <para>
   <command>FREEZE</command> is a special-purpose option that
   causes tuples to be marked <quote>frozen</quote> as soon as possible,
   rather than waiting until they are quite old.  If this is done when there
   are no other open transactions in the same database, then it is guaranteed
   that all tuples in the database are <quote>frozen</> and will not be
   subject to transaction ID wraparound problems, no matter how long the
   database is left un-vacuumed.
   <command>FREEZE</command> is not recommended for routine use.  Its only
   intended usage is in connection with preparation of user-defined template
   databases, or other databases that are completely read-only and will not
   receive routine maintenance <command>VACUUM</> operations.
   See the <citetitle>Administrator's Guide</> for details.
  </para>
  <refsect2 id="R2-SQL-VACUUM-3">
   <refsect2info>
    <date>2001-07-10</date>
   </refsect2info>
   <title>
    Notes
   </title>

   <para>
    We recommend that active production databases be
    <command>VACUUM</command>-ed frequently (at least nightly), in order to
    remove expired rows. After adding or deleting a large number
    of records, it may be a good idea to issue a <command>VACUUM
    ANALYZE</command> command for the affected table. This will update the
    system catalogs with
    the results of all recent changes, and allow the
    <productname>PostgreSQL</productname> query optimizer to make better
    choices in planning user queries.
   </para>

   <para>
    The <option>FULL</option> option is not recommended for routine use,
    but may be useful in special cases.  An example is when you have deleted
    most of the rows in a table and would like the table to physically shrink
    to occupy less disk space.  <command>VACUUM FULL</command> will usually
    shrink the table more than a plain <command>VACUUM</command> would.
   </para>

  </refsect2>
 </refsect1>

 <refsect1 id="R1-SQL-VACUUM-2">
  <title>
   Usage
  </title>
  <para>
   The following is an example from running <command>VACUUM</command> on a table
   in the regression database:

   <programlisting>
regression=> VACUUM VERBOSE ANALYZE onek;
INFO:  --Relation onek--
INFO:  Index onek_unique1: Pages 14; Tuples 1000: Deleted 3000.
        CPU 0.00s/0.11u sec elapsed 0.12 sec.
INFO:  Index onek_unique2: Pages 16; Tuples 1000: Deleted 3000.
        CPU 0.00s/0.10u sec elapsed 0.10 sec.
INFO:  Index onek_hundred: Pages 13; Tuples 1000: Deleted 3000.
        CPU 0.00s/0.10u sec elapsed 0.10 sec.
INFO:  Index onek_stringu1: Pages 31; Tuples 1000: Deleted 3000.
        CPU 0.01s/0.09u sec elapsed 0.10 sec.
INFO:  Removed 3000 tuples in 70 pages.
        CPU 0.02s/0.04u sec elapsed 0.07 sec.
INFO:  Pages 94: Changed 0, Empty 0; Tup 1000: Vac 3000, Keep 0, UnUsed 0.
        Total CPU 0.05s/0.45u sec elapsed 0.59 sec.
INFO:  Analyzing onek
VACUUM
   </programlisting>
  </para>
 </refsect1>

 <refsect1 id="R1-SQL-VACUUM-3">
  <title>
   Compatibility
  </title>

  <refsect2 id="R2-SQL-VACUUM-4">
   <refsect2info>
    <date>1998-10-04</date>
   </refsect2info>
   <title>
    SQL92
   </title>
   <para>
    There is no <command>VACUUM</command> statement in <acronym>SQL92</acronym>.
   </para>
  </refsect2>
 </refsect1>
</refentry>

<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->