From 9581d1299ca61b07a0d36ab1fcb8f8a38a6ab4fb Mon Sep 17 00:00:00 2001 From: benoit Date: Mon, 10 May 2021 11:19:08 +0200 Subject: [PATCH] Fix encoding errors #149 When the encoding of a database is not UTF8. Queries with special caracters might crash pg_activity with the message : UnicodeDecodeError: 'utf-8' codec can't decode byte 0xe9 in position 26: ++ invalid continuation byte This patch fixes the issue by querying pg_database.encoding and using it to encode the string. --- pgactivity/queries/get_blocking.sql | 31 ++++++++++--------- .../queries/get_blocking_post_90200.sql | 31 ++++++++++--------- pgactivity/queries/get_pg_activity.sql | 29 ++++++++--------- .../queries/get_pg_activity_post_100000.sql | 29 ++++++++--------- .../queries/get_pg_activity_post_110000.sql | 31 ++++++++++--------- .../queries/get_pg_activity_post_90200.sql | 25 ++++++++------- .../queries/get_pg_activity_post_90600.sql | 25 ++++++++------- pgactivity/queries/get_waiting.sql | 27 ++++++++-------- pgactivity/queries/get_waiting_post_90200.sql | 23 +++++++------- 9 files changed, 132 insertions(+), 119 deletions(-) diff --git a/pgactivity/queries/get_blocking.sql b/pgactivity/queries/get_blocking.sql index 13d698bae..e641bdc40 100644 --- a/pgactivity/queries/get_blocking.sql +++ b/pgactivity/queries/get_blocking.sql @@ -2,7 +2,7 @@ SELECT pid, application_name, - datname AS database, + sq.datname AS database, usename AS user, client, relation, @@ -17,7 +17,7 @@ SELECT END AS state, CASE WHEN sq.query LIKE '%%' THEN NULL - ELSE sq.query + ELSE convert_from(sq.query::bytea, coalesce(pg_catalog.pg_encoding_to_char(b.encoding), 'UTF8')) END AS query FROM ( @@ -27,6 +27,7 @@ SELECT pg_stat_activity.current_query AS query, blocking.mode, pg_stat_activity.datname, + pg_stat_activity.datid, pg_stat_activity.usename, CASE WHEN pg_stat_activity.client_addr IS NULL THEN 'local' @@ -59,6 +60,7 @@ SELECT pg_stat_activity.current_query AS query, blocking.mode, pg_stat_activity.datname, + pg_stat_activity.datid, pg_stat_activity.usename, CASE WHEN pg_stat_activity.client_addr IS NULL THEN 'local' @@ -89,17 +91,18 @@ SELECT ELSE extract(epoch from now() - {duration_column}) > %(min_duration)s END ) AS sq -GROUP BY - pid, - application_name, - query, - mode, - locktype, - duration, - datname, - usename, - client, - state, - relation + LEFT OUTER JOIN pg_database b ON sq.datid = b.oid +--GROUP BY +-- pid, +-- application_name, +-- query, +-- mode, +-- locktype, +-- duration, +-- sq.datname, +-- usename, +-- client, +-- state, +-- relation ORDER BY duration DESC; diff --git a/pgactivity/queries/get_blocking_post_90200.sql b/pgactivity/queries/get_blocking_post_90200.sql index 42950ef73..d51bd43dc 100644 --- a/pgactivity/queries/get_blocking_post_90200.sql +++ b/pgactivity/queries/get_blocking_post_90200.sql @@ -2,7 +2,7 @@ SELECT pid, application_name, - datname AS database, + sq.datname AS database, usename AS user, client, relation, @@ -10,7 +10,7 @@ SELECT locktype AS type, duration, state, - query + convert_from(sq.query::bytea, coalesce(pg_catalog.pg_encoding_to_char(b.encoding), 'UTF8')) AS query FROM ( SELECT @@ -19,6 +19,7 @@ SELECT pg_stat_activity.query, blocking.mode, pg_stat_activity.datname, + pg_stat_activity.datid, pg_stat_activity.usename, CASE WHEN pg_stat_activity.client_addr IS NULL THEN 'local' @@ -52,6 +53,7 @@ SELECT pg_stat_activity.query, blocking.mode, pg_stat_activity.datname, + pg_stat_activity.datid, pg_stat_activity.usename, CASE WHEN pg_stat_activity.client_addr IS NULL THEN 'local' @@ -82,17 +84,18 @@ SELECT ELSE extract(epoch from now() - {duration_column}) > %(min_duration)s END ) AS sq -GROUP BY - pid, - application_name, - query, - mode, - locktype, - duration, - datname, - usename, - client, - state, - relation + LEFT OUTER JOIN pg_database b ON sq.datid = b.oid +--GROUP BY +-- pid, +-- application_name, +-- query, +-- mode, +-- locktype, +-- duration, +-- sq.datname, +-- usename, +-- client, +-- state, +-- relation ORDER BY duration DESC; diff --git a/pgactivity/queries/get_pg_activity.sql b/pgactivity/queries/get_pg_activity.sql index 2f4b41e5a..47e2c8083 100644 --- a/pgactivity/queries/get_pg_activity.sql +++ b/pgactivity/queries/get_pg_activity.sql @@ -1,28 +1,29 @@ -- Get data from pg_activity before pg 9.2 SELECT - pg_stat_activity.procpid AS pid, + a.procpid AS pid, '' AS application_name, - pg_stat_activity.datname AS database, - CASE WHEN pg_stat_activity.client_addr IS NULL + a.datname AS database, + CASE WHEN a.client_addr IS NULL THEN 'local' - ELSE pg_stat_activity.client_addr::TEXT + ELSE a.client_addr::TEXT END AS client, - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) AS duration, - pg_stat_activity.waiting AS wait, - pg_stat_activity.usename AS user, + EXTRACT(epoch FROM (NOW() - a.{duration_column})) AS duration, + a.waiting AS wait, + a.usename AS user, CASE - WHEN pg_stat_activity.current_query = ' in transaction (aborted)' THEN 'idle in transaction (aborted)' - WHEN pg_stat_activity.current_query = ' in transaction' THEN 'idle in transaction' - WHEN pg_stat_activity.current_query = '' THEN 'idle' + WHEN a.current_query = ' in transaction (aborted)' THEN 'idle in transaction (aborted)' + WHEN a.current_query = ' in transaction' THEN 'idle in transaction' + WHEN a.current_query = '' THEN 'idle' ELSE 'active' END AS state, CASE - WHEN pg_stat_activity.current_query LIKE '%%' THEN NULL - ELSE pg_stat_activity.current_query + WHEN a.current_query LIKE '%%' THEN NULL + ELSE convert_from(a.current_query::bytea, coalesce(pg_catalog.pg_encoding_to_char(b.encoding), 'UTF8')) END AS query, false AS is_parallel_worker FROM - pg_stat_activity + pg_stat_activity a + LEFT OUTER JOIN pg_database b ON a.datid = b.oid WHERE current_query <> '' AND procpid <> pg_backend_pid() @@ -31,4 +32,4 @@ SELECT ELSE extract(epoch from now() - {duration_column}) > %(min_duration)s END ORDER BY - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) DESC + EXTRACT(epoch FROM (NOW() - a.{duration_column})) DESC diff --git a/pgactivity/queries/get_pg_activity_post_100000.sql b/pgactivity/queries/get_pg_activity_post_100000.sql index 9ccd986c1..8f4428d12 100644 --- a/pgactivity/queries/get_pg_activity_post_100000.sql +++ b/pgactivity/queries/get_pg_activity_post_100000.sql @@ -1,26 +1,27 @@ -- Get data from pg_activity from pg 10 to pg 11 -- We assume a background_worker with a not null query is a parallel worker. SELECT - pg_stat_activity.pid AS pid, - pg_stat_activity.application_name AS application_name, - pg_stat_activity.datname AS database, - CASE WHEN pg_stat_activity.client_addr IS NULL + a.pid AS pid, + a.application_name AS application_name, + a.datname AS database, + CASE WHEN a.client_addr IS NULL THEN 'local' - ELSE pg_stat_activity.client_addr::TEXT + ELSE a.client_addr::TEXT END AS client, - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) AS duration, - CASE WHEN pg_stat_activity.wait_event_type IN ('LWLock', 'Lock', 'BufferPin') + EXTRACT(epoch FROM (NOW() - a.{duration_column})) AS duration, + CASE WHEN a.wait_event_type IN ('LWLock', 'Lock', 'BufferPin') THEN true ELSE false END AS wait, - pg_stat_activity.usename AS user, - pg_stat_activity.state AS state, - pg_stat_activity.query AS query, - ( pg_stat_activity.backend_type = 'background worker' - AND pg_stat_activity.query IS NOT NULL + a.usename AS user, + a.state AS state, + convert_from(a.query::bytea, coalesce(pg_catalog.pg_encoding_to_char(b.encoding), 'UTF8')) AS query, + ( a.backend_type = 'background worker' + AND a.query IS NOT NULL ) AS is_parallel_worker FROM - pg_stat_activity + pg_stat_activity a + LEFT OUTER JOIN pg_database b ON a.datid = b.oid WHERE state <> 'idle' AND pid <> pg_backend_pid() @@ -29,4 +30,4 @@ SELECT ELSE extract(epoch from now() - {duration_column}) > %(min_duration)s END ORDER BY - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) DESC; + EXTRACT(epoch FROM (NOW() - a.{duration_column})) DESC; diff --git a/pgactivity/queries/get_pg_activity_post_110000.sql b/pgactivity/queries/get_pg_activity_post_110000.sql index cea23ff09..68a6a041c 100644 --- a/pgactivity/queries/get_pg_activity_post_110000.sql +++ b/pgactivity/queries/get_pg_activity_post_110000.sql @@ -1,29 +1,30 @@ -- Get data from pg_activity since pg 11 SELECT - pg_stat_activity.pid AS pid, - pg_stat_activity.application_name AS application_name, - pg_stat_activity.datname AS database, - CASE WHEN pg_stat_activity.client_addr IS NULL + a.pid AS pid, + a.application_name AS application_name, + a.datname AS database, + CASE WHEN a.client_addr IS NULL THEN 'local' - ELSE pg_stat_activity.client_addr::TEXT + ELSE a.client_addr::TEXT END AS client, - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) AS duration, - CASE WHEN pg_stat_activity.wait_event_type IN ('LWLock', 'Lock', 'BufferPin') + EXTRACT(epoch FROM (NOW() - a.{duration_column})) AS duration, + CASE WHEN a.wait_event_type IN ('LWLock', 'Lock', 'BufferPin') THEN true ELSE false END AS wait, - pg_stat_activity.usename AS user, - pg_stat_activity.state AS state, - pg_stat_activity.query AS query, - pg_stat_activity.backend_type = 'parallel worker' AS is_parallel_worker + a.usename AS user, + a.state AS state, + convert_from(a.query::bytea, coalesce(pg_catalog.pg_encoding_to_char(b.encoding), 'UTF8')) AS query, + a.backend_type = 'parallel worker' AS is_parallel_worker FROM - pg_stat_activity + pg_stat_activity a + LEFT OUTER JOIN pg_database b ON a.datid = b.oid WHERE - state <> 'idle' - AND pid <> pg_backend_pid() + a.state <> 'idle' + AND a.pid <> pg_catalog.pg_backend_pid() AND CASE WHEN %(min_duration)s = 0 THEN true ELSE extract(epoch from now() - {duration_column}) > %(min_duration)s END ORDER BY - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) DESC; + EXTRACT(epoch FROM (NOW() - a.{duration_column})) DESC; diff --git a/pgactivity/queries/get_pg_activity_post_90200.sql b/pgactivity/queries/get_pg_activity_post_90200.sql index 12609ed28..63f4e7aac 100644 --- a/pgactivity/queries/get_pg_activity_post_90200.sql +++ b/pgactivity/queries/get_pg_activity_post_90200.sql @@ -1,20 +1,21 @@ -- Get data from pg_activity from pg 9.2 to pg 9.5 SELECT - pg_stat_activity.pid AS pid, - pg_stat_activity.application_name AS application_name, - pg_stat_activity.datname AS database, - CASE WHEN pg_stat_activity.client_addr IS NULL + a.pid AS pid, + a.application_name AS application_name, + a.datname AS database, + CASE WHEN a.client_addr IS NULL THEN 'local' - ELSE pg_stat_activity.client_addr::TEXT + ELSE a.client_addr::TEXT END AS client, - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) AS duration, - pg_stat_activity.waiting AS wait, - pg_stat_activity.usename AS user, - pg_stat_activity.state AS state, - pg_stat_activity.query AS query, + EXTRACT(epoch FROM (NOW() - a.{duration_column})) AS duration, + a.waiting AS wait, + a.usename AS user, + a.state AS state, + convert_from(a.query::bytea, coalesce(pg_catalog.pg_encoding_to_char(b.encoding), 'UTF8')) AS query, false AS is_parallel_worker FROM - pg_stat_activity + pg_stat_activity a + LEFT OUTER JOIN pg_database b ON a.datid = b.oid WHERE state <> 'idle' AND pid <> pg_backend_pid() @@ -23,4 +24,4 @@ SELECT ELSE extract(epoch from now() - {duration_column}) > %(min_duration)s END ORDER BY - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) DESC; + EXTRACT(epoch FROM (NOW() - a.{duration_column})) DESC; diff --git a/pgactivity/queries/get_pg_activity_post_90600.sql b/pgactivity/queries/get_pg_activity_post_90600.sql index d4d21b5b7..cc01e1806 100644 --- a/pgactivity/queries/get_pg_activity_post_90600.sql +++ b/pgactivity/queries/get_pg_activity_post_90600.sql @@ -1,21 +1,22 @@ -- Get data from pg_activity from pg 9.6 to 10 -- In this versiosn there is no way to distinguish parallel workers from the rest SELECT - pg_stat_activity.pid AS pid, - pg_stat_activity.application_name AS application_name, - pg_stat_activity.datname AS database, - CASE WHEN pg_stat_activity.client_addr IS NULL + a.pid AS pid, + a.application_name AS application_name, + a.datname AS database, + CASE WHEN a.client_addr IS NULL THEN 'local' - ELSE pg_stat_activity.client_addr::TEXT + ELSE a.client_addr::TEXT END AS client, - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) AS duration, - pg_stat_activity.wait_event IS NOT NULL AS wait, - pg_stat_activity.usename AS user, - pg_stat_activity.state AS state, - pg_stat_activity.query AS query, + EXTRACT(epoch FROM (NOW() - a.{duration_column})) AS duration, + a.wait_event IS NOT NULL AS wait, + a.usename AS user, + a.state AS state, + convert_from(a.query::bytea, coalesce(pg_catalog.pg_encoding_to_char(b.encoding), 'UTF8')) AS query, false AS is_parallel_worker FROM - pg_stat_activity + pg_stat_activity a + LEFT OUTER JOIN pg_database b ON a.datid = b.oid WHERE state <> 'idle' AND pid <> pg_backend_pid() @@ -24,4 +25,4 @@ SELECT ELSE extract(epoch from now() - {duration_column}) > %(min_duration)s END ORDER BY - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) DESC; + EXTRACT(epoch FROM (NOW() - a.{duration_column})) DESC; diff --git a/pgactivity/queries/get_waiting.sql b/pgactivity/queries/get_waiting.sql index c04b6f695..b2acaaaaf 100644 --- a/pgactivity/queries/get_waiting.sql +++ b/pgactivity/queries/get_waiting.sql @@ -2,35 +2,36 @@ SELECT pg_locks.pid AS pid, '' AS application_name, - pg_stat_activity.datname AS database, - pg_stat_activity.usename AS user, - CASE WHEN pg_stat_activity.client_addr IS NULL + a.datname AS database, + a.usename AS user, + CASE WHEN a.client_addr IS NULL THEN 'local' - ELSE pg_stat_activity.client_addr::TEXT + ELSE a.client_addr::TEXT END AS client, pg_locks.mode AS mode, pg_locks.locktype AS type, pg_locks.relation::regclass AS relation, - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) AS duration, + EXTRACT(epoch FROM (NOW() - a.{duration_column})) AS duration, CASE - WHEN pg_stat_activity.current_query = ' in transaction (aborted)' THEN 'idle in transaction (aborted)' - WHEN pg_stat_activity.current_query = ' in transaction' THEN 'idle in transaction' - WHEN pg_stat_activity.current_query = '' THEN 'idle' + WHEN a.current_query = ' in transaction (aborted)' THEN 'idle in transaction (aborted)' + WHEN a.current_query = ' in transaction' THEN 'idle in transaction' + WHEN a.current_query = '' THEN 'idle' ELSE 'active' END AS state, - CASE WHEN pg_stat_activity.current_query LIKE '%%' + CASE WHEN a.current_query LIKE '%%' THEN NULL - ELSE pg_stat_activity.current_query + ELSE convert_from(a.current_query::bytea, coalesce(pg_catalog.pg_encoding_to_char(b.encoding), 'UTF8')) END AS query FROM pg_catalog.pg_locks - JOIN pg_catalog.pg_stat_activity ON(pg_catalog.pg_locks.pid = pg_catalog.pg_stat_activity.procpid) + JOIN pg_catalog.pg_stat_activity a ON (pg_catalog.pg_locks.pid = a.procpid) + LEFT OUTER JOIN pg_database b ON a.datid = b.oid WHERE NOT pg_catalog.pg_locks.granted - AND pg_catalog.pg_stat_activity.procpid <> pg_backend_pid() + AND pg_catalog.a.procpid <> pg_backend_pid() AND CASE WHEN %(min_duration)s = 0 THEN true ELSE extract(epoch from now() - {duration_column}) > %(min_duration)s END ORDER BY - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) DESC; + EXTRACT(epoch FROM (NOW() - a.{duration_column})) DESC; diff --git a/pgactivity/queries/get_waiting_post_90200.sql b/pgactivity/queries/get_waiting_post_90200.sql index f782b002d..80f868207 100644 --- a/pgactivity/queries/get_waiting_post_90200.sql +++ b/pgactivity/queries/get_waiting_post_90200.sql @@ -1,28 +1,29 @@ -- Get waiting queries for versions >= 9.2 SELECT pg_locks.pid AS pid, - pg_stat_activity.application_name AS application_name, - pg_stat_activity.datname AS database, - pg_stat_activity.usename AS user, - CASE WHEN pg_stat_activity.client_addr IS NULL + a.application_name AS application_name, + a.datname AS database, + a.usename AS user, + CASE WHEN a.client_addr IS NULL THEN 'local' - ELSE pg_stat_activity.client_addr::TEXT + ELSE a.client_addr::TEXT END AS client, pg_locks.mode AS mode, pg_locks.locktype AS type, pg_locks.relation::regclass AS relation, - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) AS duration, - pg_stat_activity.state as state, - pg_stat_activity.query AS query + EXTRACT(epoch FROM (NOW() - a.{duration_column})) AS duration, + a.state as state, + convert_from(a.query::bytea, coalesce(pg_catalog.pg_encoding_to_char(b.encoding), 'UTF8')) AS query FROM pg_catalog.pg_locks - JOIN pg_catalog.pg_stat_activity ON(pg_catalog.pg_locks.pid = pg_catalog.pg_stat_activity.pid) + JOIN pg_catalog.pg_stat_activity a ON(pg_catalog.pg_locks.pid = a.pid) + LEFT OUTER JOIN pg_database b ON a.datid = b.oid WHERE NOT pg_catalog.pg_locks.granted - AND pg_catalog.pg_stat_activity.pid <> pg_backend_pid() + AND a.pid <> pg_backend_pid() AND CASE WHEN %(min_duration)s = 0 THEN true ELSE extract(epoch from now() - {duration_column}) > %(min_duration)s END ORDER BY - EXTRACT(epoch FROM (NOW() - pg_stat_activity.{duration_column})) DESC; + EXTRACT(epoch FROM (NOW() - a.{duration_column})) DESC;