From 349a17765e291754fb67ddbc1a5df8238357f5b7 Mon Sep 17 00:00:00 2001 From: Akshay Gupta Date: Thu, 18 Oct 2018 18:49:42 +0530 Subject: [PATCH 01/13] Update README.md --- README.md | 47 +++++++++++++++++++++++++++++++++++++++++++++-- 1 file changed, 45 insertions(+), 2 deletions(-) diff --git a/README.md b/README.md index aaaecd0..147bb35 100644 --- a/README.md +++ b/README.md @@ -16,12 +16,40 @@ These queries can be run periodically to send data to your monitoring system. Th ## Queries -### query_status +### current_queries_status (pg9.x) ```sql PREPARE current_queries_status AS SELECT count(pid), query, waiting from pg_stat_activity group by query, waiting; ``` +### current_queries_status_with_locks (pg9.x) +```sql +PREPARE current_queries_status_with_locks AS +SELECT count(pg_stat_activity.pid) AS number_of_queries, + substring(trim(LEADING + FROM query) + FROM 0 + FOR 200) AS query_name, + max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, \\ + waiting, + usename, + locktype, + mode, + granted + FROM pg_stat_activity + LEFT JOIN pg_locks ON pg_stat_activity.pid = pg_locks.pid + WHERE query != '' + AND query NOT ILIKE '%pg_%' AND query NOT ILIKE '%application_name%' AND query NOT ILIKE '%inet%' + AND age(CURRENT_TIMESTAMP, query_start) > '50 milliseconds'::interval + GROUP BY query_name, + waiting, + usename, + locktype, + mode, + granted + ORDER BY max_wait_time DESC; +``` + ### query_stats ```sql PREPARE query_stats AS @@ -257,7 +285,7 @@ ORDER BY relname; ## Replication -### replication_status +### replication_status (pg9.x) ```sql PREPARE replication_status AS SELECT application_name,client_addr,state,sent_location,write_location,replay_location, @@ -271,3 +299,18 @@ SELECT application_name,client_addr,state,sent_location,write_location,replay_lo FROM pg_stat_replication) AS s; ``` +### replication_status (pg10) +```sql +PREPARE replication_status AS +SELECT application_name,client_addr,state, \\ + (sent_offset - (replay_offset - (sent_xlog - replay_xlog) * 255 * 16 ^ 6 ))::text AS byte_lag \\ + FROM (SELECT \\ + application_name,client_addr,state,sync_state,sent_lsn,write_lsn,replay_lsn, \\ + ('x' || lpad(split_part(sent_lsn::text, '/', 1), 8, '0'))::bit(32)::bigint AS sent_xlog, \\ + ('x' || lpad(split_part(replay_lsn::text, '/', 1), 8, '0'))::bit(32)::bigint AS replay_xlog, \\ + ('x' || lpad(split_part(sent_lsn::text, '/', 2), 8, '0'))::bit(32)::bigint AS sent_offset, \\ + ('x' || lpad(split_part(replay_lsn::text, '/', 2), 8, '0'))::bit(32)::bigint AS replay_offset \\ + FROM pg_stat_replication) \\ + AS s +``` + From d5d9a98a13c8ceb41950b9dad21517c7f03b0f33 Mon Sep 17 00:00:00 2001 From: Akshay Gupta Date: Thu, 18 Oct 2018 18:53:24 +0530 Subject: [PATCH 02/13] Update monitor.sql --- monitor.sql | 39 ++++++++++++++++++++++++++++++++++++++- 1 file changed, 38 insertions(+), 1 deletion(-) diff --git a/monitor.sql b/monitor.sql index 18e099f..31fbffc 100644 --- a/monitor.sql +++ b/monitor.sql @@ -204,9 +204,34 @@ WHERE EXISTS(SELECT * FROM pg_available_extensions WHERE name = 'pg_stat_statements') ORDER BY calls DESC; +PREPARE current_queries_status_with_locks AS +SELECT count(pg_stat_activity.pid) AS number_of_queries, + substring(trim(LEADING + FROM query) + FROM 0 + FOR 200) AS query_name, + max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, + waiting, + usename, + locktype, + mode, + granted + FROM pg_stat_activity + LEFT JOIN pg_locks ON pg_stat_activity.pid = pg_locks.pid + WHERE query != '' + AND query NOT ILIKE '%pg_%' AND query NOT ILIKE '%application_name%' AND query NOT ILIKE '%inet%' + AND age(CURRENT_TIMESTAMP, query_start) > '3 milliseconds'::interval + GROUP BY query_name, + waiting, + usename, + locktype, + mode, + granted + ORDER BY max_wait_time DESC; + -- replication -PREPARE replication_status AS +PREPARE replication_status_9 AS SELECT application_name,client_addr,state,sent_location,write_location,replay_location, (sent_offset - (replay_offset - (sent_xlog - replay_xlog) * 255 * 16 ^ 6 ))::text AS byte_lag FROM (SELECT @@ -217,3 +242,15 @@ SELECT application_name,client_addr,state,sent_location,write_location,replay_lo ('x' || lpad(split_part(replay_location::text, '/', 2), 8, '0'))::bit(32)::bigint AS replay_offset FROM pg_stat_replication) AS s; + +PREPARE replication_status_10 AS +SELECT application_name,client_addr,state, \\ + (sent_offset - (replay_offset - (sent_xlog - replay_xlog) * 255 * 16 ^ 6 ))::text AS byte_lag \\ + FROM (SELECT \\ + application_name,client_addr,state,sync_state,sent_lsn,write_lsn,replay_lsn, \\ + ('x' || lpad(split_part(sent_lsn::text, '/', 1), 8, '0'))::bit(32)::bigint AS sent_xlog, \\ + ('x' || lpad(split_part(replay_lsn::text, '/', 1), 8, '0'))::bit(32)::bigint AS replay_xlog, \\ + ('x' || lpad(split_part(sent_lsn::text, '/', 2), 8, '0'))::bit(32)::bigint AS sent_offset, \\ + ('x' || lpad(split_part(replay_lsn::text, '/', 2), 8, '0'))::bit(32)::bigint AS replay_offset \\ + FROM pg_stat_replication) \\ + AS s; From 068a84ed186b7c16f4e03c8a64ab70a0491f3a41 Mon Sep 17 00:00:00 2001 From: Akshay Gupta Date: Thu, 18 Oct 2018 18:53:36 +0530 Subject: [PATCH 03/13] Update README.md --- README.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/README.md b/README.md index 147bb35..a355f1b 100644 --- a/README.md +++ b/README.md @@ -311,6 +311,6 @@ SELECT application_name,client_addr,state, \\ ('x' || lpad(split_part(sent_lsn::text, '/', 2), 8, '0'))::bit(32)::bigint AS sent_offset, \\ ('x' || lpad(split_part(replay_lsn::text, '/', 2), 8, '0'))::bit(32)::bigint AS replay_offset \\ FROM pg_stat_replication) \\ - AS s + AS s; ``` From a773d9196c296f8387f2157dbdf05d5d6a7dcab7 Mon Sep 17 00:00:00 2001 From: Akshay Gupta Date: Thu, 18 Oct 2018 18:57:07 +0530 Subject: [PATCH 04/13] Update README.md --- README.md | 9 +++++---- 1 file changed, 5 insertions(+), 4 deletions(-) diff --git a/README.md b/README.md index a355f1b..a385cc2 100644 --- a/README.md +++ b/README.md @@ -26,10 +26,11 @@ SELECT count(pid), query, waiting from pg_stat_activity group by query, waiting; ```sql PREPARE current_queries_status_with_locks AS SELECT count(pg_stat_activity.pid) AS number_of_queries, - substring(trim(LEADING - FROM query) - FROM 0 - FOR 200) AS query_name, + substring(trim(LEADING \ + FROM regexp_replace(pg_stat_activity.query, '[\n\r]+'::text, + ' '::text, 'g'::text)) \ + FROM 0 \ + FOR 100) AS query_name, max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, \\ waiting, usename, From 0a89b00c68485c3fdb540057e403ba467a9b38ee Mon Sep 17 00:00:00 2001 From: Akshay Gupta Date: Thu, 18 Oct 2018 18:57:46 +0530 Subject: [PATCH 05/13] Update monitor.sql --- monitor.sql | 9 +++++---- 1 file changed, 5 insertions(+), 4 deletions(-) diff --git a/monitor.sql b/monitor.sql index 31fbffc..0c001bc 100644 --- a/monitor.sql +++ b/monitor.sql @@ -206,10 +206,11 @@ ORDER BY calls DESC; PREPARE current_queries_status_with_locks AS SELECT count(pg_stat_activity.pid) AS number_of_queries, - substring(trim(LEADING - FROM query) - FROM 0 - FOR 200) AS query_name, + substring(trim(LEADING \ + FROM regexp_replace(pg_stat_activity.query, '[\n\r]+'::text, + ' '::text, 'g'::text)) \ + FROM 0 \ + FOR 100) AS query_name, max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, waiting, usename, From a6eb696d7feaa1a3d45aeac6e6ef6ee83cebe2b8 Mon Sep 17 00:00:00 2001 From: Akshay Gupta Date: Thu, 18 Oct 2018 18:58:31 +0530 Subject: [PATCH 06/13] Update README.md --- README.md | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/README.md b/README.md index a385cc2..4ff5522 100644 --- a/README.md +++ b/README.md @@ -26,12 +26,12 @@ SELECT count(pid), query, waiting from pg_stat_activity group by query, waiting; ```sql PREPARE current_queries_status_with_locks AS SELECT count(pg_stat_activity.pid) AS number_of_queries, - substring(trim(LEADING \ + substring(trim(LEADING FROM regexp_replace(pg_stat_activity.query, '[\n\r]+'::text, - ' '::text, 'g'::text)) \ - FROM 0 \ + ' '::text, 'g'::text)) + FROM 0 FOR 100) AS query_name, - max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, \\ + max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, waiting, usename, locktype, From 512d7ce8ac23e2806b8f0284a54f138aa92e7990 Mon Sep 17 00:00:00 2001 From: Akshay Gupta Date: Thu, 18 Oct 2018 18:58:57 +0530 Subject: [PATCH 07/13] Update monitor.sql --- monitor.sql | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/monitor.sql b/monitor.sql index 0c001bc..70db14a 100644 --- a/monitor.sql +++ b/monitor.sql @@ -206,10 +206,10 @@ ORDER BY calls DESC; PREPARE current_queries_status_with_locks AS SELECT count(pg_stat_activity.pid) AS number_of_queries, - substring(trim(LEADING \ + substring(trim(LEADING FROM regexp_replace(pg_stat_activity.query, '[\n\r]+'::text, - ' '::text, 'g'::text)) \ - FROM 0 \ + ' '::text, 'g'::text)) + FROM 0 FOR 100) AS query_name, max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, waiting, From df7f5ede13e6de558398f759cd6745a1fb6661d9 Mon Sep 17 00:00:00 2001 From: Akshay Gupta Date: Thu, 18 Oct 2018 19:02:18 +0530 Subject: [PATCH 08/13] Update README.md --- README.md | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/README.md b/README.md index 4ff5522..1fd3954 100644 --- a/README.md +++ b/README.md @@ -30,7 +30,7 @@ SELECT count(pg_stat_activity.pid) AS number_of_queries, FROM regexp_replace(pg_stat_activity.query, '[\n\r]+'::text, ' '::text, 'g'::text)) FROM 0 - FOR 100) AS query_name, + FOR 200) AS query_name, max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, waiting, usename, @@ -41,7 +41,7 @@ SELECT count(pg_stat_activity.pid) AS number_of_queries, LEFT JOIN pg_locks ON pg_stat_activity.pid = pg_locks.pid WHERE query != '' AND query NOT ILIKE '%pg_%' AND query NOT ILIKE '%application_name%' AND query NOT ILIKE '%inet%' - AND age(CURRENT_TIMESTAMP, query_start) > '50 milliseconds'::interval + AND age(CURRENT_TIMESTAMP, query_start) > '5 milliseconds'::interval GROUP BY query_name, waiting, usename, From ac81ce62c56e944c4d3d0828f2bc03a1c733b86a Mon Sep 17 00:00:00 2001 From: Akshay Gupta Date: Thu, 18 Oct 2018 19:02:45 +0530 Subject: [PATCH 09/13] Update monitor.sql --- monitor.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/monitor.sql b/monitor.sql index 70db14a..faa44e6 100644 --- a/monitor.sql +++ b/monitor.sql @@ -210,7 +210,7 @@ SELECT count(pg_stat_activity.pid) AS number_of_queries, FROM regexp_replace(pg_stat_activity.query, '[\n\r]+'::text, ' '::text, 'g'::text)) FROM 0 - FOR 100) AS query_name, + FOR 200) AS query_name, max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, waiting, usename, @@ -221,7 +221,7 @@ SELECT count(pg_stat_activity.pid) AS number_of_queries, LEFT JOIN pg_locks ON pg_stat_activity.pid = pg_locks.pid WHERE query != '' AND query NOT ILIKE '%pg_%' AND query NOT ILIKE '%application_name%' AND query NOT ILIKE '%inet%' - AND age(CURRENT_TIMESTAMP, query_start) > '3 milliseconds'::interval + AND age(CURRENT_TIMESTAMP, query_start) > '5 milliseconds'::interval GROUP BY query_name, waiting, usename, From 93c73a898b8047c65bde9de052af7c81515243c3 Mon Sep 17 00:00:00 2001 From: Unnikrishnan Date: Fri, 19 Oct 2018 09:59:54 +0530 Subject: [PATCH 10/13] Add current_queries_status_with_locks for pg10 --- README.md | 29 +++++++++++++++++++++++++++++ 1 file changed, 29 insertions(+) diff --git a/README.md b/README.md index 1fd3954..e0cfc4f 100644 --- a/README.md +++ b/README.md @@ -51,6 +51,35 @@ SELECT count(pg_stat_activity.pid) AS number_of_queries, ORDER BY max_wait_time DESC; ``` +### current_queries_status_with_locks (pg10) +```sql +PREPARE current_queries_status_with_locks AS +SELECT count(pg_stat_activity.pid) AS number_of_queries, + substring(trim(LEADING + FROM regexp_replace(pg_stat_activity.query, '[\n\r]+'::text, + ' '::text, 'g'::text)) + FROM 0 + FOR 200) AS query_name, + max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, + wait_event, + usename, + locktype, + mode, + granted + FROM pg_stat_activity + LEFT JOIN pg_locks ON pg_stat_activity.pid = pg_locks.pid + WHERE query != '' + AND query NOT ILIKE '%pg_%' AND query NOT ILIKE '%application_name%' AND query NOT ILIKE '%inet%' + AND age(CURRENT_TIMESTAMP, query_start) > '5 milliseconds'::interval + GROUP BY query_name, + wait_event, + usename, + locktype, + mode, + granted + ORDER BY max_wait_time DESC; +``` + ### query_stats ```sql PREPARE query_stats AS From 872aa7134669bff3bb274f7ae77ec0b6a50e8668 Mon Sep 17 00:00:00 2001 From: Unnikrishnan Date: Fri, 19 Oct 2018 10:02:38 +0530 Subject: [PATCH 11/13] Add current_queries_status_with_locks for pg10 --- monitor.sql | 28 +++++++++++++++++++++++++++- 1 file changed, 27 insertions(+), 1 deletion(-) diff --git a/monitor.sql b/monitor.sql index faa44e6..e41431a 100644 --- a/monitor.sql +++ b/monitor.sql @@ -229,7 +229,33 @@ SELECT count(pg_stat_activity.pid) AS number_of_queries, mode, granted ORDER BY max_wait_time DESC; - + + +PREPARE current_queries_status_with_locks_pg10 AS +SELECT count(pg_stat_activity.pid) AS number_of_queries, + substring(trim(LEADING + FROM regexp_replace(pg_stat_activity.query, '[\n\r]+'::text, + ' '::text, 'g'::text)) + FROM 0 + FOR 200) AS query_name, + max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, + wait_event, + usename, + locktype, + mode, + granted + FROM pg_stat_activity + LEFT JOIN pg_locks ON pg_stat_activity.pid = pg_locks.pid + WHERE query != '' + AND query NOT ILIKE '%pg_%' AND query NOT ILIKE '%application_name%' AND query NOT ILIKE '%inet%' + AND age(CURRENT_TIMESTAMP, query_start) > '5 milliseconds'::interval + GROUP BY query_name, + wait_event, + usename, + locktype, + mode, + granted + ORDER BY max_wait_time DESC; -- replication PREPARE replication_status_9 AS From 87076edef7b29223aca830276b33aa9ae2d2bce5 Mon Sep 17 00:00:00 2001 From: Divyansh Tripathi Date: Sun, 30 Apr 2023 11:42:47 +0530 Subject: [PATCH 12/13] Adds query to analyze Long Running Queries This enables your to queries running for more than x Minutes (5 here). This lets you see what might be hogging up your CPU and network pool. Crucial in determining what might take your DB down in high traffic. --- README.md | 19 +++++++++++++++++++ 1 file changed, 19 insertions(+) diff --git a/README.md b/README.md index e0cfc4f..edf2514 100644 --- a/README.md +++ b/README.md @@ -94,6 +94,25 @@ ORDER BY calls DESC; - This requires [pg_stat_statements](http://www.postgresql.org/docs/current/static/pgstatstatements.html) to be set up. It's a part of the contrib package, and needs to be added to `shared_preload_libraries` in `postgresql.conf`. +## Long Running Queries +``` +sql +SELECT + pid, + user, + pg_stat_activity.query_start, + now() - pg_stat_activity.query_start AS query_time, + query, + state, + wait_event_type, + wait_event +FROM pg_stat_activity +WHERE (now() - pg_stat_activity.query_start) > interval '5 minutes'; +``` + +This enables your to queries running for more than x Minutes (5 here). This gives you visibility as what might be hogging up your CPU and network pool. +Crucial in determining what might take your DB down in high traffic. + ## Cache ### cache_tables ```sql From e18f853f980eba44efbc59f649b495208dd6cf01 Mon Sep 17 00:00:00 2001 From: Divyansh Tripathi Date: Mon, 8 May 2023 15:41:17 +0530 Subject: [PATCH 13/13] Update Long running query typo --- README.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/README.md b/README.md index edf2514..8c8a6e2 100644 --- a/README.md +++ b/README.md @@ -110,7 +110,7 @@ FROM pg_stat_activity WHERE (now() - pg_stat_activity.query_start) > interval '5 minutes'; ``` -This enables your to queries running for more than x Minutes (5 here). This gives you visibility as what might be hogging up your CPU and network pool. +This enables you to know the queries running for more than x Minutes (5 here). This gives you visibility as what might be hogging up your CPU and network pool. Crucial in determining what might take your DB down in high traffic. ## Cache