mirror of https://github.com/postgres/postgres
a separate statement (though it can still be invoked as part of VACUUM, too). pg_statistic redesigned to be more flexible about what statistics are stored. ANALYZE now collects a list of several of the most common values, not just one, plus a histogram (not just the min and max values). Random sampling is used to make the process reasonably fast even on very large tables. The number of values and histogram bins collected is now user-settable via an ALTER TABLE command. There is more still to do; the new stats are not being used everywhere they could be in the planner. But the remaining changes for this project should be localized, and the behavior is already better than before. A not-very-related change is that sorting now makes use of btree comparison routines if it can find one, rather than invoking '<' twice.REL7_2_STABLE
parent
9583aea9d0
commit
f905d65ee3
@ -0,0 +1,219 @@ |
||||
<!-- |
||||
$Header: /cvsroot/pgsql/doc/src/sgml/ref/analyze.sgml,v 1.1 2001/05/07 00:43:15 tgl Exp $ |
||||
Postgres documentation |
||||
--> |
||||
|
||||
<refentry id="SQL-ANALYZE"> |
||||
<refmeta> |
||||
<refentrytitle id="sql-analyze-title"> |
||||
ANALYZE |
||||
</refentrytitle> |
||||
<refmiscinfo>SQL - Language Statements</refmiscinfo> |
||||
</refmeta> |
||||
<refnamediv> |
||||
<refname> |
||||
ANALYZE |
||||
</refname> |
||||
<refpurpose> |
||||
Collect statistics about a <productname>Postgres</productname> database |
||||
</refpurpose> |
||||
</refnamediv> |
||||
<refsynopsisdiv> |
||||
<refsynopsisdivinfo> |
||||
<date>2001-05-04</date> |
||||
</refsynopsisdivinfo> |
||||
<synopsis> |
||||
ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<replaceable class="PARAMETER">column</replaceable> [, ...] ) ] ] |
||||
</synopsis> |
||||
|
||||
<refsect2 id="R2-SQL-ANALYZE-1"> |
||||
<refsect2info> |
||||
<date>2001-05-04</date> |
||||
</refsect2info> |
||||
<title> |
||||
Inputs |
||||
</title> |
||||
|
||||
<para> |
||||
<variablelist> |
||||
<varlistentry> |
||||
<term>VERBOSE</term> |
||||
<listitem> |
||||
<para> |
||||
Enables display of progress messages. |
||||
</para> |
||||
</listitem> |
||||
</varlistentry> |
||||
<varlistentry> |
||||
<term><replaceable class="PARAMETER">table</replaceable></term> |
||||
<listitem> |
||||
<para> |
||||
The name of a specific table to analyze. Defaults to all tables. |
||||
</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-ANALYZE-2"> |
||||
<refsect2info> |
||||
<date>2001-05-04</date> |
||||
</refsect2info> |
||||
<title> |
||||
Outputs |
||||
</title> |
||||
<para> |
||||
|
||||
<variablelist> |
||||
<varlistentry> |
||||
<term><computeroutput> |
||||
<returnvalue>ANALYZE</returnvalue> |
||||
</computeroutput></term> |
||||
<listitem> |
||||
<para> |
||||
The command is complete. |
||||
</para> |
||||
</listitem> |
||||
</varlistentry> |
||||
|
||||
</variablelist> |
||||
</para> |
||||
</refsect2> |
||||
</refsynopsisdiv> |
||||
|
||||
<refsect1 id="R1-SQL-ANALYZE-1"> |
||||
<refsect1info> |
||||
<date>2001-05-04</date> |
||||
</refsect1info> |
||||
<title> |
||||
Description |
||||
</title> |
||||
<para> |
||||
<command>ANALYZE</command> collects statistics about the contents of |
||||
<productname>Postgres</productname> tables, and stores the results in |
||||
the system table <literal>pg_statistic</literal>. Subsequently, |
||||
the query planner uses the statistics to help determine the most efficient |
||||
execution plans for queries. |
||||
</para> |
||||
|
||||
<para> |
||||
With no parameter, <command>ANALYZE</command> examines every table in the |
||||
current database. With a parameter, <command>ANALYZE</command> examines |
||||
only that table. It is further possible to give a list of column names, |
||||
in which case only the statistics for those columns are updated. |
||||
</para> |
||||
|
||||
<refsect2 id="R2-SQL-ANALYZE-3"> |
||||
<refsect2info> |
||||
<date>2001-05-04</date> |
||||
</refsect2info> |
||||
<title> |
||||
Notes |
||||
</title> |
||||
|
||||
<para> |
||||
It is a good idea to run <command>ANALYZE</command> periodically, or |
||||
just after making major changes in the contents of a table. Accurate |
||||
statistics will help the planner to choose the most appropriate query |
||||
plan, and thereby improve the speed of query processing. A common |
||||
strategy is to run <command>VACUUM</command> and <command>ANALYZE</command> |
||||
once a day during a low-usage time of day. |
||||
</para> |
||||
|
||||
<para> |
||||
Unlike <xref linkend="sql-vacuum" endterm="sql-vacuum-title">, |
||||
<command>ANALYZE</command> requires |
||||
only a read lock on the target table, so it can run in parallel with |
||||
other activity on the table. |
||||
</para> |
||||
|
||||
<para> |
||||
For large tables, <command>ANALYZE</command> takes a random sample of the |
||||
table contents, rather than examining every row. This allows even very |
||||
large tables to be analyzed in a small amount of time. Note however |
||||
that the statistics are only approximate, and will change slightly each |
||||
time <command>ANALYZE</command> is run, even if the actual table contents |
||||
did not change. This may result in small changes in the planner's |
||||
estimated costs shown by <command>EXPLAIN</command>. |
||||
</para> |
||||
|
||||
<para> |
||||
The collected statistics usually include a list of some of the most common |
||||
values in each column and a histogram showing the approximate data |
||||
distribution in each column. One or both of these may be omitted if |
||||
<command>ANALYZE</command> deems them uninteresting (for example, in |
||||
a unique-key column, there are no common values) or if the column |
||||
datatype does not support the appropriate operators. |
||||
</para> |
||||
|
||||
<para> |
||||
The extent of analysis can be controlled by adjusting the per-column |
||||
statistics target with <command>ALTER TABLE ALTER COLUMN SET |
||||
STATISTICS</command> (see |
||||
<xref linkend="sql-altertable" endterm="sql-altertable-title">). The |
||||
target value sets the maximum number of entries in the most-common-value |
||||
list and the maximum number of bins in the histogram. The default |
||||
target value is 10, but this can be adjusted up or down to trade off |
||||
accuracy of planner estimates against the time taken for |
||||
<command>ANALYZE</command> and the |
||||
amount of space occupied in <literal>pg_statistic</literal>. |
||||
In particular, setting the statistics target to zero disables collection of |
||||
statistics for that column. It may be useful to do that for columns that |
||||
are never used as part of the WHERE, GROUP BY, or ORDER BY clauses of |
||||
queries, since the planner will have no use for statistics on such columns. |
||||
</para> |
||||
|
||||
<para> |
||||
The largest statistics target among the columns being analyzed determines |
||||
the number of table rows sampled to prepare the statistics. Increasing |
||||
the target causes a proportional increase in the time and space needed |
||||
to do <command>ANALYZE</command>. |
||||
</para> |
||||
|
||||
</refsect2> |
||||
</refsect1> |
||||
|
||||
<refsect1 id="R1-SQL-ANALYZE-3"> |
||||
<title> |
||||
Compatibility |
||||
</title> |
||||
|
||||
<refsect2 id="R2-SQL-ANALYZE-4"> |
||||
<refsect2info> |
||||
<date>2001-05-04</date> |
||||
</refsect2info> |
||||
<title> |
||||
SQL92 |
||||
</title> |
||||
<para> |
||||
There is no <command>ANALYZE</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: |
||||
--> |
||||
File diff suppressed because it is too large
Load Diff
File diff suppressed because it is too large
Load Diff
@ -1,129 +1,27 @@ |
||||
/*-------------------------------------------------------------------------
|
||||
* |
||||
* vacuum.h |
||||
* header file for postgres vacuum cleaner |
||||
* header file for postgres vacuum cleaner and statistics analyzer |
||||
* |
||||
* |
||||
* Portions Copyright (c) 1996-2001, PostgreSQL Global Development Group |
||||
* Portions Copyright (c) 1994, Regents of the University of California |
||||
* |
||||
* $Id: vacuum.h,v 1.34 2001/03/22 04:00:43 momjian Exp $ |
||||
* $Id: vacuum.h,v 1.35 2001/05/07 00:43:25 tgl Exp $ |
||||
* |
||||
*------------------------------------------------------------------------- |
||||
*/ |
||||
#ifndef VACUUM_H |
||||
#define VACUUM_H |
||||
|
||||
#include "catalog/pg_attribute.h" |
||||
#include "catalog/pg_index.h" |
||||
#include "fmgr.h" |
||||
#include "nodes/pg_list.h" |
||||
#include "storage/itemptr.h" |
||||
#include "nodes/parsenodes.h" |
||||
|
||||
|
||||
typedef struct VAttListData |
||||
{ |
||||
int val_dummy; |
||||
struct VAttListData *val_next; |
||||
} VAttListData; |
||||
|
||||
typedef VAttListData *VAttList; |
||||
|
||||
typedef struct VacPageData |
||||
{ |
||||
BlockNumber blkno; /* BlockNumber of this Page */ |
||||
Size free; /* FreeSpace on this Page */ |
||||
uint16 offsets_used; /* Number of OffNums used by vacuum */ |
||||
uint16 offsets_free; /* Number of OffNums free or to be free */ |
||||
OffsetNumber offsets[1]; /* Array of its OffNums */ |
||||
} VacPageData; |
||||
|
||||
typedef VacPageData *VacPage; |
||||
|
||||
typedef struct VacPageListData |
||||
{ |
||||
int empty_end_pages;/* Number of "empty" end-pages */ |
||||
int num_pages; /* Number of pages in pagedesc */ |
||||
int num_allocated_pages; /* Number of allocated pages in
|
||||
* pagedesc */ |
||||
VacPage *pagedesc; /* Descriptions of pages */ |
||||
} VacPageListData; |
||||
|
||||
typedef VacPageListData *VacPageList; |
||||
|
||||
typedef struct |
||||
{ |
||||
Form_pg_attribute attr; |
||||
Datum best, |
||||
guess1, |
||||
guess2, |
||||
max, |
||||
min; |
||||
int best_len, |
||||
guess1_len, |
||||
guess2_len, |
||||
max_len, |
||||
min_len; |
||||
long best_cnt, |
||||
guess1_cnt, |
||||
guess1_hits, |
||||
guess2_hits, |
||||
null_cnt, |
||||
nonnull_cnt, |
||||
max_cnt, |
||||
min_cnt; |
||||
FmgrInfo f_cmpeq, |
||||
f_cmplt, |
||||
f_cmpgt; |
||||
Oid op_cmplt; |
||||
regproc outfunc; |
||||
Oid typelem; |
||||
bool initialized; |
||||
} VacAttrStats; |
||||
|
||||
typedef struct VRelListData |
||||
{ |
||||
Oid vrl_relid; |
||||
struct VRelListData *vrl_next; |
||||
} VRelListData; |
||||
|
||||
typedef VRelListData *VRelList; |
||||
|
||||
typedef struct VTupleLinkData |
||||
{ |
||||
ItemPointerData new_tid; |
||||
ItemPointerData this_tid; |
||||
} VTupleLinkData; |
||||
|
||||
typedef VTupleLinkData *VTupleLink; |
||||
|
||||
typedef struct VTupleMoveData |
||||
{ |
||||
ItemPointerData tid; /* tuple ID */ |
||||
VacPage vacpage; /* where to move */ |
||||
bool cleanVpd; /* clean vacpage before using */ |
||||
} VTupleMoveData; |
||||
|
||||
typedef VTupleMoveData *VTupleMove; |
||||
|
||||
typedef struct VRelStats |
||||
{ |
||||
Oid relid; |
||||
int num_tuples; |
||||
int num_pages; |
||||
Size min_tlen; |
||||
Size max_tlen; |
||||
bool hasindex; |
||||
int num_vtlinks; |
||||
VTupleLink vtlinks; |
||||
} VRelStats; |
||||
|
||||
extern bool VacuumRunning; |
||||
|
||||
extern void vc_abort(void); |
||||
extern void vacuum(char *vacrel, bool verbose, bool analyze, List *anal_cols); |
||||
extern void analyze_rel(Oid relid, List *anal_cols2, int MESSAGE_LEVEL); |
||||
|
||||
#define ATTNVALS_SCALE 1000000000 /* XXX so it can act as a float4 */ |
||||
/* in commands/vacuum.c */ |
||||
extern void vacuum(VacuumStmt *vacstmt); |
||||
extern void vac_update_relstats(Oid relid, long num_pages, double num_tuples, |
||||
bool hasindex); |
||||
/* in commands/analyze.c */ |
||||
extern void analyze_rel(Oid relid, VacuumStmt *vacstmt); |
||||
|
||||
#endif /* VACUUM_H */ |
||||
|
||||
Loading…
Reference in new issue