CREATE STATISTICS CREATE STATISTICS 7 SQL - Language Statements CREATE STATISTICS define extended statistics CREATE STATISTICS [ IF NOT EXISTS ] statistics_name [ ( statistic_type [, ... ] ) ] ON column_name, column_name [, ...] FROM table_name Description CREATE STATISTICS 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. If a schema name is given (for example, CREATE STATISTICS myschema.mystat ...) 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. Parameters IF NOT EXISTS 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. statistics_name The name (optionally schema-qualified) of the statistics object to be created. statistic_type A statistic type to be computed in this statistics object. Currently supported types are ndistinct, which enables n-distinct coefficient tracking, and dependencies, which enables functional dependencies. column_name The name of a table column to be included in the statistics object. table_name The name (optionally schema-qualified) of the table containing the column(s) the statistics are computed on. Notes You must be the owner of a table to create or change statistics on it. Examples Create table t1 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 dependencies are built on those columns: CREATE TABLE t1 ( a int, b int ); INSERT INTO t1 SELECT i/100, i/500 FROM generate_series(1,1000000) s(i); CREATE STATISTICS s1 (dependencies) ON a, b FROM t1; ANALYZE t1; -- valid combination of values EXPLAIN ANALYZE SELECT * FROM t1 WHERE (a = 1) AND (b = 0); -- invalid combination of values EXPLAIN ANALYZE SELECT * FROM t1 WHERE (a = 1) AND (b = 1); Without functional-dependency statistics, the planner would make the same estimate of the number of matching rows for these two queries. With such statistics, it is able to tell that one case has matches and the other does not. Compatibility There is no CREATE STATISTICS command in the SQL standard. See Also