[[["容易理解","easyToUnderstand","thumb-up"],["確實解決了我的問題","solvedMyProblem","thumb-up"],["其他","otherUp","thumb-up"]],[["難以理解","hardToUnderstand","thumb-down"],["資訊或程式碼範例有誤","incorrectInformationOrSampleCode","thumb-down"],["缺少我需要的資訊/範例","missingTheInformationSamplesINeed","thumb-down"],["翻譯問題","translationIssue","thumb-down"],["其他","otherDown","thumb-down"]],["上次更新時間:2025-09-04 (世界標準時間)。"],[[["\u003cp\u003eThis guide provides instructions on how to monitor AlloyDB Omni database performance using various PostgreSQL observability scripts.\u003c/p\u003e\n"],["\u003cp\u003eYou can monitor connected processes and wait events by querying the \u003ccode\u003epg_stat_activity\u003c/code\u003e view, including identifying process states, transaction ages, and wait event details.\u003c/p\u003e\n"],["\u003cp\u003eBy using the \u003ccode\u003epg_stat_user_tables\u003c/code\u003e view, you can determine the size of your largest tables, view top sequential scans, and view top index scans.\u003c/p\u003e\n"],["\u003cp\u003eYou can identify the longest-running transactions using the \u003ccode\u003epg_stat_activity\u003c/code\u003e view and monitor vacuum operation progress by querying \u003ccode\u003epg_stat_progress_vacuum\u003c/code\u003e and \u003ccode\u003epg_stat_activity\u003c/code\u003e views.\u003c/p\u003e\n"],["\u003cp\u003eThe document also details methods to view asynchronous queries, identify blocking lock SQL, and assess the effectiveness of \u003ccode\u003ework_mem\u003c/code\u003e and \u003ccode\u003etemp_buffers\u003c/code\u003e settings for performance optimization.\u003c/p\u003e\n"]]],[],null,["# Monitor AlloyDB Omni database performance\n\nSelect a documentation version: 15.7.0keyboard_arrow_down\n\n- [Current (16.8.0)](/alloydb/omni/current/docs/monitor-performance)\n- [16.8.0](/alloydb/omni/16.8.0/docs/monitor-performance)\n- [16.3.0](/alloydb/omni/16.3.0/docs/monitor-performance)\n- [15.12.0](/alloydb/omni/15.12.0/docs/monitor-performance)\n- [15.7.1](/alloydb/omni/15.7.1/docs/monitor-performance)\n- [15.7.0](/alloydb/omni/15.7.0/docs/monitor-performance)\n\n\u003cbr /\u003e\n\n| **Note:** Your use of AlloyDB Omni is subject to the agreement between you and Google that governs Google Cloud offerings. If you do not have a Google Cloud account, or have not otherwise entered into an agreement with Google that governs Google Cloud offerings, please do not proceed or download this software until you have done so. To create a Google Cloud account, see [the Google Cloud homepage](/docs/get-started).\n\n\u003cbr /\u003e\n\nThis page describes how to monitor your AlloyDB Omni database\nperformance using PostgreSQL observability scripts.\n\nView state of connected processes and wait events\n-------------------------------------------------\n\nYou can determine any processes connected to your AlloyDB Omni\ninstance as well as any backends that are waiting for activity by querying the\n`pg_stat_activity` view. \n\n SELECT\n pid,\n datname,\n age(backend_xid) AS age_in_xids,\n now() - xact_start AS xact_age,\n now() - query_start AS query_age,\n state,\n wait_event_type,\n wait_event,\n query_id,\n query\n FROM\n pg_stat_activity\n WHERE\n state != 'idle'\n AND pid \u003c\u003e pg_backend_pid()\n ORDER BY\n 4 DESC\n LIMIT 10;\n\nView largest tables\n-------------------\n\nYou can determine the size of your largest tables by querying the\n`pg_stat_user_tables` view. \n\n SELECT\n oid,\n oid::regclass table_name,\n pg_size_pretty(pg_relation_size(oid)),\n relpages,\n s.seq_scan,\n s.idx_scan\n FROM\n pg_class,\n pg_stat_user_tables s\n WHERE\n s.relid = oid\n AND oid \u003e 16383\n AND relpages \u003e 100\n AND relkind = 'r'\n ORDER BY\n relpages DESC\n LIMIT 20;\n\nView top sequential scans\n-------------------------\n\nYou can view the top sequential scans by querying the `pg_stat_user_tables`\nview. \n\n SELECT\n relid,\n relname,\n seq_scan,\n pg_size_pretty(pg_relation_size(relid))\n FROM\n pg_stat_user_tables\n ORDER BY\n seq_scan DESC\n LIMIT 15;\n\nView top index scans\n--------------------\n\nYou can view the top index scans by querying the `pg_stat_user_tables` view. \n\n SELECT\n relid,\n relid::regclass table_name,\n idx_scan,\n pg_size_pretty(pg_relation_size(relid))\n FROM\n pg_stat_user_tables\n WHERE\n idx_scan \u003e 10\n ORDER BY\n idx_scan DESC\n LIMIT 15;\n\nView longest running transactions\n---------------------------------\n\nYou can view the longest running transactions by querying the\n`pg_stat_activity` view and checking the age of the transaction. \n\n SELECT\n pid,\n age(backend_xid) AS age_in_xids,\n now() - xact_start AS xact_age,\n now() - query_start AS query_age,\n state,\n query\n FROM\n pg_stat_activity\n WHERE\n state != 'idle'\n ORDER BY\n 2 DESC\n LIMIT 10;\n\nCheck vacuum progress\n---------------------\n\nYou can check the progress of vacuum operations by querying the\n`pg_stat_progress_vacuum` view and joining it with the `pg_stat_activity` view\nusing process IDs. \n\n SELECT\n p.pid,\n now() - a.xact_start AS duration,\n coalesce(wait_event_type ||'.'|| wait_event, 'f') AS waiting,\n CASE\n WHEN a.query ~*'^autovacuum.*to prevent wraparound' THEN 'wraparound'\n WHEN a.query ~*'^vacuum' THEN 'user'\n ELSE\n 'regular'\n END AS mode,\n p.datname AS database,\n p.relid::regclass AS table,\n p.phase,\n pg_size_pretty(p.heap_blks_total * current_setting('block_size')::int) AS table_size,\n pg_size_pretty(pg_total_relation_size(relid)) AS total_size,\n pg_size_pretty(p.heap_blks_scanned * current_setting('block_size')::int) AS scanned,\n pg_size_pretty(p.heap_blks_vacuumed * current_setting('block_size')::int) AS vacuumed,\n round(100.0 * p.heap_blks_scanned / p.heap_blks_total, 1) AS scanned_pct,\n round(100.0 * p.heap_blks_vacuumed / p.heap_blks_total, 1) AS vacuumed_pct,\n p.index_vacuum_count,\n round(100.0 * p.num_dead_tuples / p.max_dead_tuples,1) AS dead_pct\n FROM pg_stat_progress_vacuum p\n JOIN pg_stat_activity a using (pid)\n ORDER BY now() - a.xact_start DESC;\n\nView asynchronous queries\n-------------------------\n\nTo view queries that are running asynchronously, you can query the\n`pg_stat_activity` view and filter for queries that are not the leader process. \n\n SELECT\n query,\n leader_pid,\n array_agg(pid) FILTER (WHERE leader_pid != pid) AS members\n FROM\n pg_stat_activity\n WHERE\n leader_pid IS NOT NULL\n GROUP BY\n query,\n leader_pid;\n\nView blocking lock SQL\n----------------------\n\nYou can view activity that is blocked by querying the `pg_locks` view and\njoining it with the `pg_stat_activity` view. \n\n SELECT blocked_locks.pid AS blocked_pid,\n blocked_activity.usename AS blocked_user,\n blocking_locks.pid AS blocking_pid,\n blocking_activity.usename AS blocking_user,\n blocked_activity.query AS blocked_statement,\n blocked_activity.wait_event AS blocked_wait_event,\n blocking_activity.wait_event AS blocking_wait_event,\n blocking_activity.query AS current_statement_in_blocking_process\n FROM pg_catalog.pg_locks blocked_locks\n JOIN pg_catalog.pg_stat_activity blocked_activity ON blocked_activity.pid = blocked_locks.pid\n JOIN pg_catalog.pg_locks blocking_locks\n ON blocking_locks.locktype = blocked_locks.locktype\n AND blocking_locks.database IS NOT DISTINCT FROM blocked_locks.database\n AND blocking_locks.relation IS NOT DISTINCT FROM blocked_locks.relation\n AND blocking_locks.page IS NOT DISTINCT FROM blocked_locks.page\n AND blocking_locks.tuple IS NOT DISTINCT FROM blocked_locks.tuple\n AND blocking_locks.virtualxid IS NOT DISTINCT FROM blocked_locks.virtualxid\n AND blocking_locks.transactionid IS NOT DISTINCT FROM blocked_locks.transactionid\n AND blocking_locks.classid IS NOT DISTINCT FROM blocked_locks.classid\n AND blocking_locks.objid IS NOT DISTINCT FROM blocked_locks.objid\n AND blocking_locks.objsubid IS NOT DISTINCT FROM blocked_locks.objsubid\n AND blocking_locks.pid != blocked_locks.pid\n JOIN pg_catalog.pg_stat_activity blocking_activity ON blocking_activity.pid = blocking_locks.pid\n WHERE NOT blocked_locks.granted;\n\nDetermine `work_mem` and `temp_buffers` size effectiveness\n----------------------------------------------------------\n\nTo determine if your `work_mem` and `temp_buffers` are sized correctly for your\nneeds, you can query `pg_stat_database` view and check the `postgres.log` file.\nUsing `pg_stat_database`, execute the following query and if there is any growth\nin `temp_files` or `temp_bytes` between executions, then tuning is likely\nnecessary for either `work_mem` or `temp_buffers`. \n\n SELECT\n datname,\n temp_files,\n temp_bytes\n FROM\n pg_stat_database;\n\nAfter running this, check the `postgres.log` file to see if temporary files were\nused:\n\n`LOG: [fd.c:1772] temporary file: path \"base/pgsql_tmp/pgsql_tmp4640.1\", size 139264`\n\nThe goal is to minimize the creation of temporary files, not completely prevent\nthem from happening. This is because setting both `work_mem` and `temp_buffers`\nis a balance between available memory on the host and the number of connections\nthat require the memory. Setting these parameters correctly requires\nunderstanding about each individual workload."]]