mirror of
https://github.com/postgres/postgres.git
synced 2025-08-21 10:42:50 +03:00
Statistics defined by the CREATE STATISTICS command are only used to assist with the selectivity estimations of base relations, never for joins. Here we mention this fact in the notes section of the CREATE STATISTICS command. Discussion: https://postgr.es/m/CAApHDvrMuVgDOrmg_EtFDZ=AOovq6EsJNnHH1ddyZ8EqL4yzMw@mail.gmail.com Backpatch-through: 11
194 lines
5.8 KiB
Plaintext
194 lines
5.8 KiB
Plaintext
<!--
|
|
doc/src/sgml/ref/create_statistics.sgml
|
|
PostgreSQL documentation
|
|
-->
|
|
|
|
<refentry id="sql-createstatistics">
|
|
<indexterm zone="sql-createstatistics">
|
|
<primary>CREATE STATISTICS</primary>
|
|
</indexterm>
|
|
|
|
<refmeta>
|
|
<refentrytitle>CREATE STATISTICS</refentrytitle>
|
|
<manvolnum>7</manvolnum>
|
|
<refmiscinfo>SQL - Language Statements</refmiscinfo>
|
|
</refmeta>
|
|
|
|
<refnamediv>
|
|
<refname>CREATE STATISTICS</refname>
|
|
<refpurpose>define extended statistics</refpurpose>
|
|
</refnamediv>
|
|
|
|
<refsynopsisdiv>
|
|
<synopsis>
|
|
CREATE STATISTICS [ IF NOT EXISTS ] <replaceable class="parameter">statistics_name</replaceable>
|
|
[ ( <replaceable class="parameter">statistics_kind</replaceable> [, ... ] ) ]
|
|
ON <replaceable class="parameter">column_name</replaceable>, <replaceable class="parameter">column_name</replaceable> [, ...]
|
|
FROM <replaceable class="parameter">table_name</replaceable>
|
|
</synopsis>
|
|
|
|
</refsynopsisdiv>
|
|
|
|
<refsect1 id="sql-createstatistics-description">
|
|
<title>Description</title>
|
|
|
|
<para>
|
|
<command>CREATE STATISTICS</command> will create a new extended statistics
|
|
object tracking data about the specified table, foreign table or
|
|
materialized view. The statistics object will be created in the current
|
|
database and will be owned by the user issuing the command.
|
|
</para>
|
|
|
|
<para>
|
|
If a schema name is given (for example, <literal>CREATE STATISTICS
|
|
myschema.mystat ...</literal>) then the statistics object is created in the
|
|
specified schema. Otherwise it is created in the current schema.
|
|
The name of the statistics object must be distinct from the name of any
|
|
other statistics object in the same schema.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Parameters</title>
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry>
|
|
<term><literal>IF NOT EXISTS</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Do not throw an error if a statistics object with the same name already
|
|
exists. A notice is issued in this case. Note that only the name of
|
|
the statistics object is considered here, not the details of its
|
|
definition.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">statistics_name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name (optionally schema-qualified) of the statistics object to be
|
|
created.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">statistics_kind</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
A statistics kind to be computed in this statistics object.
|
|
Currently supported kinds are
|
|
<literal>ndistinct</literal>, which enables n-distinct statistics, and
|
|
<literal>dependencies</literal>, which enables functional
|
|
dependency statistics.
|
|
If this clause is omitted, all supported statistics kinds are
|
|
included in the statistics object.
|
|
For more information, see <xref linkend="planner-stats-extended"/>
|
|
and <xref linkend="multivariate-statistics-examples"/>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">column_name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name of a table column to be covered by the computed statistics.
|
|
At least two column names must be given.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">table_name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name (optionally schema-qualified) of the table containing the
|
|
column(s) the statistics are computed on; see <xref
|
|
linkend="sql-analyze"/> for an explanation of the handling of
|
|
inheritance and partitions.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Notes</title>
|
|
|
|
<para>
|
|
You must be the owner of a table to create a statistics object
|
|
reading it. Once created, however, the ownership of the statistics
|
|
object is independent of the underlying table(s).
|
|
</para>
|
|
|
|
<para>
|
|
Extended statistics are not currently used by the planner for selectivity
|
|
estimations made for table joins. This limitation will likely be removed
|
|
in a future version of <productname>PostgreSQL</productname>.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1 id="sql-createstatistics-examples">
|
|
<title>Examples</title>
|
|
|
|
<para>
|
|
Create table <structname>t1</structname> with two functionally dependent columns, i.e.,
|
|
knowledge of a value in the first column is sufficient for determining the
|
|
value in the other column. Then functional dependency statistics are built
|
|
on those columns:
|
|
|
|
<programlisting>
|
|
CREATE TABLE t1 (
|
|
a int,
|
|
b int
|
|
);
|
|
|
|
INSERT INTO t1 SELECT i/100, i/500
|
|
FROM generate_series(1,1000000) s(i);
|
|
|
|
ANALYZE t1;
|
|
|
|
-- the number of matching rows will be drastically underestimated:
|
|
EXPLAIN ANALYZE SELECT * FROM t1 WHERE (a = 1) AND (b = 0);
|
|
|
|
CREATE STATISTICS s1 (dependencies) ON a, b FROM t1;
|
|
|
|
ANALYZE t1;
|
|
|
|
-- now the row count estimate is more accurate:
|
|
EXPLAIN ANALYZE SELECT * FROM t1 WHERE (a = 1) AND (b = 0);
|
|
</programlisting>
|
|
|
|
Without functional-dependency statistics, the planner would assume
|
|
that the two <literal>WHERE</literal> conditions are independent, and would
|
|
multiply their selectivities together to arrive at a much-too-small
|
|
row count estimate.
|
|
With such statistics, the planner recognizes that the <literal>WHERE</literal>
|
|
conditions are redundant and does not underestimate the row count.
|
|
</para>
|
|
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Compatibility</title>
|
|
|
|
<para>
|
|
There is no <command>CREATE STATISTICS</command> command in the SQL standard.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>See Also</title>
|
|
|
|
<simplelist type="inline">
|
|
<member><xref linkend="sql-alterstatistics"/></member>
|
|
<member><xref linkend="sql-dropstatistics"/></member>
|
|
</simplelist>
|
|
</refsect1>
|
|
</refentry>
|