1CREATE STATISTICS(7)     PostgreSQL 13.3 Documentation    CREATE STATISTICS(7)
2
3
4

NAME

6       CREATE_STATISTICS - define extended statistics
7

SYNOPSIS

9       CREATE STATISTICS [ IF NOT EXISTS ] statistics_name
10           [ ( statistics_kind [, ... ] ) ]
11           ON column_name, column_name [, ...]
12           FROM table_name
13

DESCRIPTION

15       CREATE STATISTICS will create a new extended statistics object tracking
16       data about the specified table, foreign table or materialized view. The
17       statistics object will be created in the current database and will be
18       owned by the user issuing the command.
19
20       If a schema name is given (for example, CREATE STATISTICS
21       myschema.mystat ...) then the statistics object is created in the
22       specified schema. Otherwise it is created in the current schema. The
23       name of the statistics object must be distinct from the name of any
24       other statistics object in the same schema.
25

PARAMETERS

27       IF NOT EXISTS
28           Do not throw an error if a statistics object with the same name
29           already exists. A notice is issued in this case. Note that only the
30           name of the statistics object is considered here, not the details
31           of its definition.
32
33       statistics_name
34           The name (optionally schema-qualified) of the statistics object to
35           be created.
36
37       statistics_kind
38           A statistics kind to be computed in this statistics object.
39           Currently supported kinds are ndistinct, which enables n-distinct
40           statistics, dependencies, which enables functional dependency
41           statistics, and mcv which enables most-common values lists. If this
42           clause is omitted, all supported statistics kinds are included in
43           the statistics object. For more information, see Section 14.2.2 and
44           Section 70.2.
45
46       column_name
47           The name of a table column to be covered by the computed
48           statistics. At least two column names must be given; the order of
49           the column names is insignificant.
50
51       table_name
52           The name (optionally schema-qualified) of the table containing the
53           column(s) the statistics are computed on.
54

NOTES

56       You must be the owner of a table to create a statistics object reading
57       it. Once created, however, the ownership of the statistics object is
58       independent of the underlying table(s).
59

EXAMPLES

61       Create table t1 with two functionally dependent columns, i.e.,
62       knowledge of a value in the first column is sufficient for determining
63       the value in the other column. Then functional dependency statistics
64       are built on those columns:
65
66           CREATE TABLE t1 (
67               a   int,
68               b   int
69           );
70
71           INSERT INTO t1 SELECT i/100, i/500
72                            FROM generate_series(1,1000000) s(i);
73
74           ANALYZE t1;
75
76           -- the number of matching rows will be drastically underestimated:
77           EXPLAIN ANALYZE SELECT * FROM t1 WHERE (a = 1) AND (b = 0);
78
79           CREATE STATISTICS s1 (dependencies) ON a, b FROM t1;
80
81           ANALYZE t1;
82
83           -- now the row count estimate is more accurate:
84           EXPLAIN ANALYZE SELECT * FROM t1 WHERE (a = 1) AND (b = 0);
85
86       Without functional-dependency statistics, the planner would assume that
87       the two WHERE conditions are independent, and would multiply their
88       selectivities together to arrive at a much-too-small row count
89       estimate. With such statistics, the planner recognizes that the WHERE
90       conditions are redundant and does not underestimate the row count.
91
92       Create table t2 with two perfectly correlated columns (containing
93       identical data), and a MCV list on those columns:
94
95           CREATE TABLE t2 (
96               a   int,
97               b   int
98           );
99
100           INSERT INTO t2 SELECT mod(i,100), mod(i,100)
101                            FROM generate_series(1,1000000) s(i);
102
103           CREATE STATISTICS s2 (mcv) ON a, b FROM t2;
104
105           ANALYZE t2;
106
107           -- valid combination (found in MCV)
108           EXPLAIN ANALYZE SELECT * FROM t2 WHERE (a = 1) AND (b = 1);
109
110           -- invalid combination (not found in MCV)
111           EXPLAIN ANALYZE SELECT * FROM t2 WHERE (a = 1) AND (b = 2);
112
113       The MCV list gives the planner more detailed information about the
114       specific values that commonly appear in the table, as well as an upper
115       bound on the selectivities of combinations of values that do not appear
116       in the table, allowing it to generate better estimates in both cases.
117

COMPATIBILITY

119       There is no CREATE STATISTICS command in the SQL standard.
120

SEE ALSO

122       ALTER STATISTICS (ALTER_STATISTICS(7)), DROP STATISTICS
123       (DROP_STATISTICS(7))
124
125
126
127PostgreSQL 13.3                      2021                 CREATE STATISTICS(7)
Impressum