ANALYZE
Description
ANALYZE collects statistics about ordinary tables in a database and stores the results in the pg_statistic and pg_statistic_ext system catalogs. After you run the ANALYZE command, you can query the collected statistics in the system catalogs or in the system views pg_stats and pg_ext_stats. The execution plan generator uses these statistics to generate the most effective execution plan.
If no parameters are specified, ANALYZE analyzes each table and partitioned table in the database. You can also specify table_name, column_name, and partition_name to limit the analysis to a specified table, column, or partitioned table.
Statistics collected each time are stored in historical statistics tables (gs_statistic_history, gs_statistic_ext_history, and gs_statistic_history). The number of historical tables and the retention period of statistics are specified by the GUC parameters stats_history_record_limit and stats_history_retention_time.
Precautions
- Non-temporary tables cannot be analyzed in an anonymous block, transaction block, function, or stored procedure. Temporary tables in a stored procedure can be analyzed but their statistics updates cannot be rolled back.
- The ANALYZE VERIFY operation is used to detect abnormal scenarios. The RELEASE version is required. Remote read is not triggered in the ANALYZE VERIFY scenario. Therefore, the remote read parameter does not take effect. If the system detects that a page is damaged due to an error in a key system catalog, the system directly reports an error and halts the detection.
- With no parameter specified, ANALYZE processes all the tables on which the current user has permission to analyze in the current database. With tables specified, ANALYZE processes only the specified tables.
- To analyze a table, you must be the owner of the table or a user granted the ANALYZE permission for the specified table. When separation of duties is disabled, a system administrator has this permission by default. However, database owners are allowed to analyze all tables in their databases, except shared catalogs. (The restriction for shared catalogs means that a true database-wide analyze operation can only be executed by a system administrator). ANALYZE skips tables on which users do not have permissions.
- ANALYZE does not collect columns for which comparison or equivalent operations cannot be performed, for example, columns of the cursor type.
Syntax
- Collect statistics information about a table.
ANALYZE [ VERBOSE ] [ table_name [ ( column_name [, ...] ) ] ] ;
- Collect partition statistics information about a partitioned table.
ANALYZE [ VERBOSE ] table_name [ ( column_name [, ...] ) ] PARTITION ( partition_name ) ;
If the keyword PARTITION is used, partition_name must be the name of a level-1 partition.
- Collect statistics about multiple columns manually.
ANALYZE [ VERBOSE ] table_name (( column_1_name, column_2_name [, ...] ));
- If the GUC parameter enable_functional_dependency is disabled, the statistics about a maximum of 32 columns can be collected at a time. If enable_functional_dependency is enabled, the statistics about a maximum of 4 columns can be collected at a time.
- You are not allowed to collect statistics about multiple columns in system catalogs and global temporary tables.
- Collect statistics about multiple columns automatically.
After the auto_statistic_ext_columns parameter is enabled and the ANALYZE statement is executed, multi-column statistics are automatically created based on the index prefix of the table. The number of columns in the multi-column statistics cannot exceed the value of auto_statistic_ext_columns.
For example, if index (a, b, c, d) exists in table t and auto_statistic_ext_columns is set to 4, multi-column statistics about (a, b), (a, b, c), and (a, b, c, d) are created after table t is analyzed.
ANALYZE [ VERBOSE ] table_name;
Parameters
- VERBOSE
Enables the display of progress messages.
If VERBOSE is specified, ANALYZE displays the progress information, indicating the table that is being processed. Statistics about tables are also displayed.
- table_name
Specifies the name (possibly schema-qualified) of a specific table to analyze. If omitted, all regular tables (but not foreign tables) in the current database are analyzed.
Currently, you can use ANALYZE to collect statistics only from row-store tables.
Value range: an existing table name.
- column_name, column_1_name, column_2_name
Specifies the name of a specific column to analyze. All columns are analyzed by default.
Value range: an existing column name.
- partition_name
Assumes the table is a partitioned table. You can specify partition_name following the keyword PARTITION to analyze the statistics of this table.
Value range: a partition name of a table.
Examples
-- Create a table.
m_db=# CREATE TABLE customer_info ( WR_RETURNED_DATE_SK INTEGER , WR_RETURNED_TIME_SK INTEGER , WR_ITEM_SK INTEGER NOT NULL, WR_REFUNDED_CUSTOMER_SK INTEGER );
-- Create a partitioned table.
m_db=# CREATE TABLE customer_par ( WR_RETURNED_DATE_SK INTEGER , WR_RETURNED_TIME_SK INTEGER , WR_ITEM_SK INTEGER NOT NULL, WR_REFUNDED_CUSTOMER_SK INTEGER ) PARTITION BY RANGE(WR_RETURNED_DATE_SK) ( PARTITION P1 VALUES LESS THAN(2452275), PARTITION P2 VALUES LESS THAN(2452640), PARTITION P3 VALUES LESS THAN(2453000), PARTITION P4 VALUES LESS THAN(MAXVALUE) );
-- Run the ANALYZE statement to update statistics.
m_db=# ANALYZE customer_info; m_db=# ANALYZE customer_par;
-- Run the ANALYZE VERBOSE statement to update statistics and display table information.
m_db=# ANALYZE VERBOSE customer_info; INFO: analyzing "public.customer_info"(cn_5002 pid=53078) INFO: analyzing "public.customer_info" inheritance tree(cn_5002 pid=53078) ANALYZE
If any environment-related fault occurs, check logs of the primary database node.
-- Drop the table.
m_db=# DROP TABLE customer_info; m_db=# DROP TABLE customer_par;
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot