From 34f66ea58c8280592b7312c925a1219e15d9bb2c Mon Sep 17 00:00:00 2001 From: Mohamed Ali <75553212+mmohali@users.noreply.github.com> Date: Mon, 9 Sep 2024 10:49:52 -0700 Subject: [PATCH] V3.1 --- CHANGELOG.md | 9 + README.md | 15 +- pg_collector.sql | 532 +++++++++++++++++++++++++++++++++++++++++++++-- 3 files changed, 531 insertions(+), 25 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 4f6aecd..7a66691 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -101,4 +101,13 @@ Standby/Reader DB (Read Only) 5- Add DB/username/status/Connections count to the Connections Info section . 6- Add objects list and count in each schema to the schema info section . 7- Update the Toast Tables Mapping's sql to order the toast by the size and add note about toast OID wraparound. +``` + +# v3.1 +``` +1- The script should display the message "Report Generated Successfully" upon successful completion and relocate the report file name and location information to the end of the script.. +2- Add a new section for Amazon Aurora PostgreSQL. +3- Add a new section for Invalid databases. +4- Implement a check for the pg_stat_statements extension. If the extension is not installed, the script should print the message "pg_stat_statements extension is not installed" in the report, instead of displaying the errors "ERROR: relation "pg_stat_statements_info" does not exist" or "ERROR: relation "pg_stat_statements" does not exist". + ``` \ No newline at end of file diff --git a/README.md b/README.md index 18475e9..6913ec0 100644 --- a/README.md +++ b/README.md @@ -127,7 +127,7 @@ mohamed@mydevhost ~ %ls -lhrt /tmp/pg_colletcor_* ## Notes: -1- it is ok to see below errors while executing the pg_colletcor.sql script if you did not install pg_stat_statements extension +1- It is ok to see below errors while executing the pg_colletcor.sql script if you did not install pg_stat_statements extension ``` postgres=> \i pg_collector.sql @@ -148,7 +148,7 @@ LINE 10: from pg_stat_statements postgres=> \q ``` -2- if the Database have Tens of thousands of tables , some queries can take longer time . +2- If the Database have Tens of thousands of tables , some queries can take longer time . use statement_timeout to Abort any statement that takes more than the specified number of milliseconds. please check below example . @@ -164,6 +164,17 @@ postgres=> ``` +3- It is acceptable to observe the following errors while executing the pg_collector.sql script on Amazon Aurora PostgreSQL if the Cluster Cache Manager is disabled. + +``` +postgres=> \i pg_collector.sql +Output format is html. +psql:/tmp/pg_collector.sql:2766: ERROR: Cluster Cache Manager is disabled +psql:/tmp/pg_collector.sql:2769: ERROR: Cluster Cache Manager is disabled +Report Generated Successfully +Report name and location: /tmp/pg_collector_postgres-2024-09-09_161216.html + +``` # License diff --git a/pg_collector.sql b/pg_collector.sql index 0e05bd4..464750f 100644 --- a/pg_collector.sql +++ b/pg_collector.sql @@ -4,14 +4,13 @@ -- | -- Create Date : 16 SEPT 2019 | -- | -- Description : Script to Collect PostgreSQL Database Informations | -- | and generate HTML Report | --- | -- version : V 3 | +-- | -- version : V 3.1 | -- | -- Changelog : https://github.com/awslabs/pg-collector/blob/main/CHANGELOG.md | | -- | Copyright Amazon.com, Inc. or its affiliates. All Rights Reserved. | -- | SPDX-License-Identifier: MIT-0 | -- +-----------------------------------------------------------------------------------+ \H \set filename :DBNAME-`date +%Y-%m-%d_%H%M%S` -\echo Report name and location: /tmp/pg_collector_:filename.html \o /tmp/pg_collector_:filename.html \pset footer off \qecho -\qecho

PG COLLECTOR V3

+\qecho

PG COLLECTOR V3.1

\qecho For more information about PG Collector, visit the project github repository
\qecho DB INFO
\qecho
@@ -169,6 +168,36 @@ select datname as Database_name , datistemplate as database_is_template ,datallo \qecho \qecho Triggers \qecho pg_config +\qecho Invalid databases +\qecho ****** +\qecho +\qecho +\qecho
+\qecho
+\qecho
+\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho +\qecho \qecho \qecho \qecho @@ -177,6 +206,7 @@ select datname as Database_name , datistemplate as database_is_template ,datallo \qecho
\qecho
+ -- +----------------------------------------------------------------------------+ -- | - Database_size - | -- +----------------------------------------------------------------------------+ @@ -270,6 +300,12 @@ from pg_replication_slots where active = true order by age(xmin) desc; +\qecho

Invalid databases count:

+select count(*) FROM pg_database WHERE datconnlimit = '-2' ; + + +\qecho

Invalid databases list:

+SELECT * FROM pg_database WHERE datconnlimit = '-2' ; \qecho

Orphaned prepared transactions:

@@ -339,16 +375,22 @@ ORDER BY age(relfrozenxid) DESC ; \qecho

autovacuum progress per day:

+\qecho
+\qecho

Note:

+\qecho

This section presents the number of tables that have been vacuumed by the autovacuum , grouped by the date (in the format YYYY-MM-DD) of the last_autovacuum column.

+\qecho

If the value in the date column is NULL, it indicates that the corresponding value in the table count column represents the number of tables that the autovacuum did not vacuum.

+\qecho
-select to_char(last_autovacuum, 'YYYY-MM-DD') as date, -count(*) from pg_stat_all_tables -group by to_char(last_autovacuum, 'YYYY-MM-DD') order by 1; +select to_char(last_autovacuum, 'YYYY-MM-DD') as date , count(*) as table_count from pg_stat_all_tables group by to_char(last_autovacuum, 'YYYY-MM-DD') order by 1; - -\qecho

when the last autovacuum succeeded ?

-select relname as table_name,n_live_tup, n_tup_upd, n_tup_del, n_dead_tup, + +\qecho

The most recent 20 tables that have been vacuumed by the autovacuum:

+\qecho

Note:

+\qecho

- If the value in the last_autovacuum column is NULL, it indicates that the autovacuum did not vacuum this table.

+\qecho
+select schemaname as schema_name,relname as table_name,n_live_tup, n_tup_upd, n_tup_del, n_dead_tup, last_vacuum, last_autovacuum, last_analyze, last_autoanalyze from pg_stat_all_tables order by last_autovacuum desc limit 20 ; @@ -371,7 +413,7 @@ order by 2 desc limit 20; -\qecho

Indexs Inforamtion for Top-20 tables order by xid age:

+\qecho

Index Inforamtion for Top-20 tables order by xid age:

SELECT schemaname,relname AS tablename, indexrelname AS indexname, @@ -425,6 +467,8 @@ order by 2,8 desc; \qecho
\qecho

biggest 50 tables in the DB:

\qecho
+\qecho

Note:

+\qecho

- If the table has never yet been vacuumed or analyzed, ROW_ESTIMATE column (pg_class.reltuples) contains -1 indicating that the row count is unknown.

\qecho
SELECT *, pg_size_pretty(total_bytes) AS TOTAL_PRETTY , pg_size_pretty(index_bytes) AS INDEX_PRETTY @@ -471,7 +515,7 @@ FROM pg_catalog.pg_statio_all_indexes ORDER BY 1,2 desc ; \qecho
\qecho
SELECT -schemaname,relname as "Table", +schemaname as schema_name,relname as "Table", indexrelname AS indexname, pg_relation_size(indexrelid), pg_size_pretty(pg_relation_size(indexrelid)) AS index_size @@ -523,14 +567,22 @@ SELECT p.pid, now() - a.xact_start AS duration, coalesce(wait_event_type ||'.'|| \qecho
\qecho

Autovacuum progress per day:

\qecho
+\qecho

Note:

+\qecho

This section presents the number of tables that have been vacuumed by the autovacuum , grouped by the date (in the format YYYY-MM-DD) of the last_autovacuum column.

+\qecho

If the value in the date column is NULL, it indicates that the corresponding value in the table count column represents the number of tables that the autovacuum did not vacuum.

+\qecho
\qecho
-select to_char(last_autovacuum, 'YYYY-MM-DD') as date , count(*) from pg_stat_all_tables group by to_char(last_autovacuum, 'YYYY-MM-DD') order by 1; +select to_char(last_autovacuum, 'YYYY-MM-DD') as date , count(*) as table_count from pg_stat_all_tables group by to_char(last_autovacuum, 'YYYY-MM-DD') order by 1; \qecho
\qecho
\qecho

Autoanalyze progress per day:

\qecho
+\qecho

Note:

+\qecho

This section presents the number of tables that have been analyzed by the autoanalyze , grouped by the date (in the format YYYY-MM-DD) of the last_autoanalyze column.

+\qecho

If the value in the date column is NULL, it indicates that the corresponding value in the table count column represents the number of tables that the autoanalyze did not analyze.

+\qecho
\qecho
-select to_char(last_autoanalyze, 'YYYY-MM-DD') as date , count(*) from pg_stat_all_tables group by to_char(last_autoanalyze, 'YYYY-MM-DD') order by 1; +select to_char(last_autoanalyze, 'YYYY-MM-DD') as date , count(*) as table_count from pg_stat_all_tables group by to_char(last_autoanalyze, 'YYYY-MM-DD') order by 1; \qecho
\qecho
--Which tables are currently eligible for autovacuum based on curret parameters @@ -575,7 +627,7 @@ SELECT name, setting FROM pg_settings WHERE name='track_counts'; \qecho

Top 50 tables based on number of dead tuples:

\qecho
\qecho
-select relname,n_live_tup, n_tup_upd, n_tup_del, n_dead_tup, last_vacuum, last_autovacuum, last_analyze, last_autoanalyze from pg_stat_all_tables order by n_dead_tup desc limit 50; +select schemaname as schema_name,relname AS table_name,n_live_tup, n_tup_upd, n_tup_del, n_dead_tup, last_vacuum, last_autovacuum, last_analyze, last_autoanalyze from pg_stat_all_tables order by n_dead_tup desc limit 50; \qecho
\qecho
\qecho

Tables have more than 20% dead rows :

@@ -764,6 +816,8 @@ FROM \qecho \qecho pg_stat_statements extension
\qecho
+select count(*) > 0 is_pg_stat_statements_enabled FROM pg_catalog.pg_extension where extname = 'pg_stat_statements' \gset +\if :is_pg_stat_statements_enabled \qecho

pg_stat_statements installed version:

\qecho
\qecho
@@ -898,6 +952,11 @@ shared_blks_read from pg_stat_statements order by shared_blks_read desc limit 20; \qecho
+\else + \if yes + \qecho 'pg_stat_statements extension is not installed' + \endif +\endif \qecho
[Top]

@@ -1368,11 +1427,11 @@ order by physical_reads_percent desc limit 50 ; \qecho

SELECT current_database(), schemaname, tablename, /*reltuples::bigint, relpages::bigint, otta,*/ - ROUND((CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages::FLOAT/otta END)::NUMERIC,1) AS "table_bloat_%", + ROUND((CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages::FLOAT/otta END)::NUMERIC,1) AS "table_bloat_ratio", CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::BIGINT END AS wastedbytes, pg_size_pretty(CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::BIGINT END) AS table_wasted_size, iname AS Index_nam, /*ituples::bigint, ipages::bigint, iotta,*/ - ROUND((CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages::FLOAT/iotta END)::NUMERIC,1) AS "Index_bloat_%", + ROUND((CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages::FLOAT/iotta END)::NUMERIC,1) AS "Index_bloat_ratio", CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta) END AS wastedibytes, pg_size_pretty(CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta) ::BIGINT END) AS Index_wasted_size FROM ( @@ -1416,16 +1475,16 @@ ORDER BY wastedbytes DESC; \qecho
\qecho
-\qecho

Tables and indexes Bloat [Fragmentation] order by table wasted % :

+\qecho

Tables and indexes Bloat [Fragmentation] order by table wasted ratio :

\qecho
\qecho
SELECT current_database(), schemaname, tablename, /*reltuples::bigint, relpages::bigint, otta,*/ - ROUND((CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages::FLOAT/otta END)::NUMERIC,1) AS "table_bloat_%", + ROUND((CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages::FLOAT/otta END)::NUMERIC,1) AS "table_bloat_ratio", CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::BIGINT END AS wastedbytes, pg_size_pretty(CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::BIGINT END) AS table_wasted_size, iname AS Index_nam, /*ituples::bigint, ipages::bigint, iotta,*/ - ROUND((CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages::FLOAT/iotta END)::NUMERIC,1) AS "Index_bloat_%", + ROUND((CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages::FLOAT/iotta END)::NUMERIC,1) AS "Index_bloat_ratio", CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta) END AS wastedibytes, pg_size_pretty(CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta) ::BIGINT END) AS Index_wasted_size FROM ( @@ -1469,16 +1528,16 @@ ORDER BY 4 desc; \qecho
\qecho
-\qecho

Tables and indexes Bloat [Fragmentation] order by index wasted % :

+\qecho

Tables and indexes Bloat [Fragmentation] order by index wasted ratio :

\qecho
\qecho
SELECT current_database(), schemaname, tablename, /*reltuples::bigint, relpages::bigint, otta,*/ - ROUND((CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages::FLOAT/otta END)::NUMERIC,1) AS "table_bloat_%", + ROUND((CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages::FLOAT/otta END)::NUMERIC,1) AS "table_bloat_ratio", CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::BIGINT END AS wastedbytes, pg_size_pretty(CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::BIGINT END) AS table_wasted_size, iname AS Index_nam, /*ituples::bigint, ipages::bigint, iotta,*/ - ROUND((CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages::FLOAT/iotta END)::NUMERIC,1) AS "Index_bloat_%", + ROUND((CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages::FLOAT/iotta END)::NUMERIC,1) AS "Index_bloat_ratio", CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta) END AS wastedibytes, pg_size_pretty(CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta) ::BIGINT END) AS Index_wasted_size FROM ( @@ -2500,7 +2559,14 @@ order by table_id , trigger_status_code; \qecho
\qecho

The view pg_config describes the compile-time configuration parameters of the currently installed version of PostgreSQL.

\qecho
-select * from pg_config(); +select count(*) > 0 isaurora from pg_settings where name='rds.extensions' and setting like '%aurora_stat_utils%' \gset +\if :isaurora +\qecho 'pg_config() is currently not supported for Aurora' +\else + \if yes + select * from pg_config(); + \endif +\endif \qecho
\qecho
[Top]

@@ -2520,6 +2586,31 @@ SELECT * FROM pg_settings where name in ('rds.extensions') order by category; \qecho

[Top]

+-- +----------------------------------------------------------------------------+ +-- | - Invalid_databases - | +-- +----------------------------------------------------------------------------+ + + +\qecho +\qecho Invalid databases


+\qecho
+\qecho

If the DROP DATABASE command is interrupted, the database will become invalid,starting from versions 11.21 and later, 12.16 and later, 13.12 and later, 14.9 and later, 15.4 and later, all versions of 16 as well as PostgreSQL 16 and all subsequent major versions.

+\qecho

you will not be able to connect to it again. In this case, you will see the below error message:

+\qecho

failed: FATAL: cannot connect to invalid database

+\qecho

HINT: Use DROP DATABASE to drop invalid databases.

+\qecho
+\qecho
+\qecho

Invalid databases count:

+select count(*) FROM pg_database WHERE datconnlimit = '-2' ; + +\qecho
+\qecho

Invalid databases list:

+SELECT * FROM pg_database WHERE datconnlimit = '-2' ; +\qecho
+ +\qecho
[Top]

+ + -- +----------------------------------------------------------------------------+ -- | - ************* - | -- +----------------------------------------------------------------------------+ @@ -2534,5 +2625,400 @@ SELECT * FROM pg_settings where name in ('rds.extensions') order by category; \qecho

[Top]

+-- +----------------------------------------------------------------------------+ +-- | - Aurora_version - | +-- +----------------------------------------------------------------------------+ + + +\qecho +\qecho Aurora version


+\qecho
+\qecho
+select count(*) > 0 isaurora from pg_settings where name='rds.extensions' and setting like '%aurora_stat_utils%' \gset +\if :isaurora +SELECT * FROM aurora_version(); +\else + \if yes + \qecho 'This is not Aurora instance' + \endif +\endif +\qecho
+ +\qecho
[Top]

+ + + + +-- +----------------------------------------------------------------------------+ +-- | - Aurora_PostgreSQL_built-in_functions - | +-- +----------------------------------------------------------------------------+ + + +\qecho +\qecho Aurora PostgreSQL built-in functions


+\qecho
+\qecho
+select count(*) > 0 isaurora from pg_settings where name='rds.extensions' and setting like '%aurora_stat_utils%' \gset +\if :isaurora +SELECT * FROM aurora_list_builtins(); +\else + \if yes + \qecho 'This is not Aurora instance' + \endif +\endif +\qecho
+\qecho
[Top]

+ + +-- +----------------------------------------------------------------------------+ +-- | - Aurora_db_instance_identifier - | +-- +----------------------------------------------------------------------------+ + + +\qecho +\qecho Aurora db instance identifier


+\qecho
+\qecho
+select count(*) > 0 isaurora from pg_settings where name='rds.extensions' and setting like '%aurora_stat_utils%' \gset +\if :isaurora +SELECT server_id, + CASE + WHEN 'MASTER_SESSION_ID' = session_id THEN 'writer' + ELSE 'reader' + END AS instance_role +FROM aurora_replica_status() rt, + aurora_db_instance_identifier() di + WHERE rt.server_id = di; +\else + \if yes + \qecho 'This is not Aurora instance' + \endif +\endif +\qecho
+\qecho
[Top]

+ +-- +----------------------------------------------------------------------------+ +-- | - Aurora_cluster_instances - | +-- +----------------------------------------------------------------------------+ + +\qecho +\qecho Aurora cluster instances


+\qecho
+\qecho
+select count(*) > 0 isaurora from pg_settings where name='rds.extensions' and setting like '%aurora_stat_utils%' \gset +\if :isaurora + SELECT server_id, + CASE + WHEN 'MASTER_SESSION_ID' = session_id THEN 'writer' + ELSE 'reader' + END AS instance_role +FROM aurora_replica_status() ; +\else + \if yes + \qecho 'This is not Aurora instance' + \endif +\endif +\qecho
+\qecho
[Top]

+ +-- +----------------------------------------------------------------------------+ +-- | - Aurora_reader_instances-Replica_Lag - | +-- +----------------------------------------------------------------------------+ + + +\qecho +\qecho Aurora reader instances - Replica Lag


+\qecho
+\qecho
+select count(*) > 0 isaurora from pg_settings where name='rds.extensions' and setting like '%aurora_stat_utils%' \gset +\if :isaurora +SELECT server_id, + CASE + WHEN 'MASTER_SESSION_ID' = session_id THEN 'writer' + ELSE 'reader' + END AS instance_role, + replica_lag_in_msec AS replica_lag_ms, + round(extract (epoch FROM (SELECT age(clock_timestamp(), last_update_timestamp))) * 1000) AS last_update_age_ms +FROM aurora_replica_status() +ORDER BY replica_lag_in_msec NULLS FIRST; +\else + \if yes + \qecho 'This is not Aurora instance' + \endif +\endif +\qecho
+\qecho
[Top]

+ + + +-- +----------------------------------------------------------------------------+ +-- | - Aurora_cluster_cache_management_(CCM) - | +-- +----------------------------------------------------------------------------+ + + +\qecho +\qecho Aurora cluster cache management (CCM)


+\qecho
+\qecho
+select count(*) > 0 isaurora from pg_settings where name='rds.extensions' and setting like '%aurora_stat_utils%' \gset +\if :isaurora +SELECT * FROM aurora_ccm_status(); +SELECT buffers_sent_last_minute * 8/60 AS warm_rate_kbps, +100 * (1.0-buffers_sent_last_scan/buffers_found_last_scan) AS warm_percent +FROM aurora_ccm_status (); +\else + \if yes + \qecho 'This is not Aurora instance' + \endif +\endif +\qecho
+\qecho
[Top]

+ + + +-- +----------------------------------------------------------------------------+ +-- | - Aurora_global_db_status - | +-- +----------------------------------------------------------------------------+ + + +\qecho +\qecho Aurora global db status


+\qecho
+\qecho
+select count(*) > 0 isaurora from pg_settings where name='rds.extensions' and setting like '%aurora_stat_utils%' \gset +\if :isaurora +SELECT CASE + WHEN '-1' = durability_lag_in_msec THEN 'Primary' + ELSE 'Secondary' + END AS global_role, + * + FROM aurora_global_db_status(); +\else + \if yes + \qecho 'This is not Aurora instance' + \endif +\endif +\qecho
+\qecho
[Top]

+ +-- +----------------------------------------------------------------------------+ +-- | - Aurora_wait_event_stat - | +-- +----------------------------------------------------------------------------+ + + +\qecho +\qecho Aurora wait event stat


+\qecho
+\qecho

Note:

+\qecho

aurora_stat_system_waits()function returns the cumulative number of waits and cumulative wait time for each wait event generated by the DB instance that you are currently connected to.

+\qecho

Statistics returned by this function are reset when a DB instance restarts.

+\qecho

waits :The number of times the wait event occurred.

+\qecho

wait_time : The total amount of time in microseconds spent waiting for this event.

+\qecho
+\qecho
+select count(*) > 0 isaurora from pg_settings where name='rds.extensions' and setting like '%aurora_stat_utils%' \gset +\if :isaurora +SELECT type_name as wait_event_type, + event_name as wait_event_name, + waits, + wait_time + FROM aurora_stat_system_waits() +NATURAL JOIN aurora_stat_wait_event() +NATURAL JOIN aurora_stat_wait_type() order by wait_time desc; +\else + \if yes + \qecho 'This is not Aurora instance' + \endif +\endif +\qecho
+\qecho
[Top]

+ + +-- +----------------------------------------------------------------------------+ +-- | - query_plan_management - | +-- +----------------------------------------------------------------------------+ + +\qecho +\qecho Query Plan Management (QPM)


+\qecho
+\qecho
+select count(*) > 0 isaurora from pg_settings where name='rds.extensions' and setting like '%aurora_stat_utils%' \gset +select count(*) > 0 is_apg_plan_mgmt_enabled FROM pg_catalog.pg_extension where extname = 'apg_plan_mgmt' \gset +select count(*) = 0 is_apg_plan_mgmt_not_enabled FROM pg_catalog.pg_extension where extname = 'apg_plan_mgmt' \gset +\if :isaurora + \if :is_apg_plan_mgmt_not_enabled + \qecho 'Query Plan Management (QPM) is not enabled' + \else + \if :is_apg_plan_mgmt_enabled + show rds.enable_plan_management ; + SELECT e.extname AS "Extension Name", e.extversion AS "Version", n.nspname AS "Schema",pg_get_userbyid(e.extowner) as Owner, c.description AS "Description" , e.extrelocatable as "relocatable to another schema", e.extconfig ,e.extcondition + FROM pg_catalog.pg_extension e LEFT JOIN pg_catalog.pg_namespace n ON n.oid = e.extnamespace LEFT JOIN pg_catalog.pg_description c ON c.objoid = e.oid AND c.classoid = 'pg_catalog.pg_extension'::pg_catalog.regclass + where e.extname = 'apg_plan_mgmt'; + select * from pg_available_extensions where name='apg_plan_mgmt'; + SELECT name ,version ,installed FROM pg_available_extension_versions where name='apg_plan_mgmt' order by version; + select name,setting from pg_settings where name like 'apg_plan_mgmt%'; + with plans_stored_count as (select count(*) as cnt from apg_plan_mgmt.dba_plans) + select s.setting as max_plans, p.cnt as plans_stored_count, (p.cnt/s.setting::int)*100 as plans_stored_PCT_from_max_plans from pg_settings s, plans_stored_count p where s.name ='apg_plan_mgmt.max_plans'; + \endif + \endif +\else + \if yes + \qecho 'This is not Aurora instance' + \endif +\endif +\qecho
+\qecho
[Top]

+ +-- +----------------------------------------------------------------------------+ +-- | - Aurora_dml_activity - | +-- +----------------------------------------------------------------------------+ +\qecho +\qecho Aurora dml activity


+\qecho
+\qecho
+select count(*) > 0 isaurora from pg_settings where name='rds.extensions' and setting like '%aurora_stat_utils%' \gset +\if :isaurora +with dml_details as ( +SELECT db.datname AS datname, + NULLIF(BTRIM(SPLIT_PART(db.asdmla::TEXT, ',', 1), '()'),'') AS select_count, + NULLIF(BTRIM(SPLIT_PART(db.asdmla::TEXT, ',', 2), '()'),'') AS select_latency_microsecs, + NULLIF(BTRIM(SPLIT_PART(db.asdmla::TEXT, ',', 3), '()'),'') AS insert_count, + NULLIF(BTRIM(SPLIT_PART(db.asdmla::TEXT, ',', 4), '()'),'') AS insert_latency_microsecs, + NULLIF(BTRIM(SPLIT_PART(db.asdmla::TEXT, ',', 5), '()'),'') AS update_count, + NULLIF(BTRIM(SPLIT_PART(db.asdmla::TEXT, ',', 6), '()'),'') AS update_latency_microsecs, + NULLIF(BTRIM(SPLIT_PART(db.asdmla::TEXT, ',', 7), '()'),'') AS delete_count, + NULLIF(BTRIM(SPLIT_PART(db.asdmla::TEXT, ',', 8), '()'),'') AS delete_latency_microsecs + FROM (SELECT datname, + aurora_stat_dml_activity(oid) AS asdmla + FROM pg_database --where datname = 'rathoran_db' + ) AS db) +select datname as database_name , + select_count::numeric, + select_latency_microsecs::numeric, + TRUNC(select_latency_microsecs::numeric/NULLIF(select_count::numeric,0),3) select_latency_per_exec, + insert_count::numeric, + insert_latency_microsecs::numeric, + TRUNC(insert_latency_microsecs::numeric/NULLIF(insert_count::numeric,0),3) insert_latency_per_exec, + update_count::numeric, + update_latency_microsecs::numeric, + TRUNC(update_latency_microsecs::numeric/NULLIF(update_count::numeric,0),3) update_latency_per_exec, + delete_count::numeric, + delete_latency_microsecs::numeric, + TRUNC(delete_latency_microsecs::numeric/NULLIF(delete_count::numeric,0) ,3)delete_latency_per_exec + FROM dml_details + order by select_count desc; +\else + \if yes + \qecho 'This is not Aurora instance' + \endif +\endif +\qecho
+\qecho
[Top]

+-- +----------------------------------------------------------------------------+ +-- | - process_memory_context_usage - | +-- +----------------------------------------------------------------------------+ +\qecho +\qecho Process memory context usage


+\qecho
+\qecho
+select count(*) > 0 isaurora from pg_settings where name='rds.extensions' and setting like '%aurora_stat_utils%' \gset +\if :isaurora +select count(*) > 0 isaurora1215plus FROM aurora_version() where replace(substring(aurora_version, 1, 5),'.','')::int >= '1215' \gset +\if :isaurora1215plus +\qecho
+\qecho

The allocated memory for each memory context across all the processes ordered by allocated memory:

+\qecho
+select +name, sum(allocated) as allocated_size_bytes, + pg_size_pretty(sum(allocated)) as allocated_size, + pg_size_pretty(sum(used)) as used_size, + trunc(sum(used)/sum(allocated)*100,2) as used_pct, + sum(instances) as instances_count + from aurora_stat_memctx_usage() + group by name + order by allocated_size_bytes desc; +\qecho
+\qecho

The top 50 porcess with the highest allocated memory:

+\qecho
+select +pid, sum(allocated) as allocated_size_bytes ,pg_size_pretty(sum(allocated)) as allocated_size , pg_size_pretty(sum(used)) as used_size, +trunc(sum(used)/sum(allocated)*100,2) as used_pct +from aurora_stat_memctx_usage() +group by pid order by allocated_size_bytes desc +limit 50; + +\qecho
+\qecho

The top 50 porcess with the highest allocated memory including process information in pg_stat_activity view:

+\qecho
+WITH memctx AS + (select +pid, sum(allocated) as allocated_size_bytes ,pg_size_pretty(sum(allocated)) as allocated_size , pg_size_pretty(sum(used)) as used_size, +trunc(sum(used)/sum(allocated)*100,2) as used_pct +from aurora_stat_memctx_usage() +group by pid order by allocated_size_bytes desc +limit 50 + ) +select * +from pg_stat_activity ps +INNER JOIN memctx ON ps.pid = memctx.pid +order by memctx.allocated_size_bytes desc ; +\qecho
+\qecho

The top 50 processes with the highest allocated memory and the breakdown of their memory usage of each memory context:

+\qecho
+WITH memctx as +(select +pid, sum(allocated) as allocated_size_bytes +from aurora_stat_memctx_usage() +group by pid order by allocated_size_bytes desc +limit 50 ) +select pid ,name , allocated as allocated_size_bytes ,pg_size_pretty(allocated) as allocated_size , pg_size_pretty(used) as used_size , instances as instances_count from aurora_stat_memctx_usage() where pid in +(select pid from memctx ) +order by PID, allocated_size_bytes desc; +\else + \if yes + \qecho 'aurora_stat_memctx_usage function is only available staring from Aurora PostgreSQL version 12.15' + \endif +\endif +\else + \if yes + \qecho 'This is not Aurora instance' + \endif +\endif +\qecho
+\qecho
[Top]

+ + + +-- +----------------------------------------------------------------------------+ +-- | - logical_replication_write_through_cache - | +-- +----------------------------------------------------------------------------+ + + +\qecho +\qecho Logical replication write-through cache


+\qecho
+\qecho
+select count(*) > 0 isaurora from pg_settings where name='rds.extensions' and setting like '%aurora_stat_utils%' \gset +\if :isaurora +select count(*) > 0 isaurora1212plus FROM aurora_version() where replace(substring(aurora_version, 1, 5),'.','')::int >= '1212' \gset +\if :isaurora1212plus +SELECT * FROM aurora_stat_logical_wal_cache(); +\else + \if yes + \qecho 'aurora_stat_logical_wal_cache function is only available staring from Aurora PostgreSQL version 12.12' + \endif +\endif +\else + \if yes + \qecho 'This is not Aurora instance' + \endif +\endif +\qecho
+ +\qecho
[Top]

+ + +\echo Report Generated Successfully +\echo Report name and location: /tmp/pg_collector_:filename.html \q

Amazon Aurora PostgreSQL
Aurora versionAurora PostgreSQL built-in functionsAurora db instance identifierAurora cluster instances
Aurora reader instances - Replica LagAurora cluster cache management (CCM)Aurora global db statusAurora wait event stat
Query Plan Management (QPM)Aurora DML activityprocess memory context usageLogical replication write-through cache
************************