From a7d23a21ed8ccec3b5e9258c0ff4be798caaa86e Mon Sep 17 00:00:00 2001 From: Alvar Freude Date: Sun, 8 Aug 2021 18:12:38 +0200 Subject: [PATCH] Import old Hilfsqueries.sql --- Hilfsqueries.sql | 1043 ++++++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 1043 insertions(+) create mode 100644 Hilfsqueries.sql diff --git a/Hilfsqueries.sql b/Hilfsqueries.sql new file mode 100644 index 0000000..b040929 --- /dev/null +++ b/Hilfsqueries.sql @@ -0,0 +1,1043 @@ + + +-- +-- Old SQL snippets Hilfsqueries.sql +-- +-- + + +-- Was ist gerade auf der DB los? + +-- 9.2 bis 9.5 + + + SELECT datname, pid, usename, + clock_timestamp() - xact_start AS "Trans Dauer", + clock_timestamp() - query_start AS "Query Dauer", + query, waiting + FROM pg_stat_activity + WHERE state <> 'idle' + AND pid <> pg_backend_pid() + ORDER BY "Query Dauer" DESC; + + SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + + +-- (zusammen) 9.2 bis 9.5 + + + SELECT datname, pid, usename, + clock_timestamp() - xact_start AS "Trans Dauer", + clock_timestamp() - query_start AS "Query Dauer", + query, waiting + FROM pg_stat_activity + WHERE state = 'active' + AND pid <> pg_backend_pid() + ORDER BY "Query Dauer" DESC; SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + + + + + SELECT datname, pid, usename, state, + clock_timestamp() - xact_start AS "Trans Dauer", + clock_timestamp() - query_start AS "Query Dauer", + clock_timestamp() - backend_start AS "Zeit seit Start", + clock_timestamp() - state_change AS "Zeit seit Change", + query, waiting + FROM pg_stat_activity + WHERE -- state = 'active' + -- AND + pid <> pg_backend_pid() + ORDER BY "Zeit seit Change" DESC; + + +-- Kill Lang-Idler! + +SELECT pg_terminate_backend(pid) AS terminate, pid, datname, query + FROM pg_stat_activity + WHERE state = 'idle' + AND pid <> pg_backend_pid() and clock_timestamp() - state_change > '60 minutes'::interval; + + -- AND query like 'INSERT %'; + + + + +SELECT pg_terminate_backend(pid) AS terminate, pid, datname, query + FROM pg_stat_activity + WHERE state = 'idle' + AND pid <> pg_backend_pid() and clock_timestamp() - state_change > '1 minutes'::interval + AND query like 'SET %'; + + + +-- ab 9.6 + + SELECT datname, pid, usename, + clock_timestamp() - xact_start AS "Trans Dauer", + clock_timestamp() - query_start AS "Query Dauer", + query, wait_event_type, wait_event + FROM pg_stat_activity + WHERE state = 'active' + AND pid <> pg_backend_pid() + ORDER BY "Query Dauer" DESC; SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + + + + + + SELECT datname, pid, usename, + clock_timestamp() - xact_start AS "Trans Dauer", + clock_timestamp() - query_start AS "Query Dauer", + query, wait_event_type, wait_event + FROM pg_stat_activity + WHERE state <> 'idle' + AND pid <> pg_backend_pid() + ORDER BY "Query Dauer" DESC; SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + + + + + + + + + + + SELECT datname, pid, + clock_timestamp() - xact_start AS "Trans Dauer", + clock_timestamp() - query_start AS "Query Dauer", + query, waiting + FROM pg_stat_activity + WHERE state = 'active' + AND pid <> pg_backend_pid() + ORDER BY "Query Dauer" DESC; SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + + + SELECT datname, pid, + clock_timestamp() - xact_start AS "Trans Dauer", + clock_timestamp() - query_start AS "Query Dauer", + substr(query,0,70), waiting + FROM pg_stat_activity + WHERE state = 'active' + AND pid <> pg_backend_pid() + ORDER BY "Query Dauer" DESC; SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + + + + + + + + + SELECT datname, pid, + clock_timestamp() - xact_start AS "Trans Dauer", + clock_timestamp() - query_start AS "Query Dauer", + query, waiting + FROM pg_stat_activity + WHERE pid <> pg_backend_pid() + ORDER BY "Query Dauer" DESC; SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + + + + + +-- Fuer 9.1 + + SELECT datname, clock_timestamp() - xact_start AS "Trans.Dauer", + clock_timestamp() - query_start AS "Query Dauer", + current_query + FROM pg_stat_activity + WHERE procpid <> pg_backend_pid() + AND current_query <> '' + ORDER BY "Trans.Dauer" DESC; + + + + +Nur Zähler: + +Wow, wie SQL-92 ;-) + +Ab 9.5: + +SELECT COALESCE(datname,'__TOTAL__') "Datenbank" + ,COALESCE(state,'__TOTAL__') "Status" + ,count "Anzahl" + FROM ( + SELECT datname + ,state + ,count(*) + FROM pg_stat_activity + GROUP BY CUBE (1,2) +) AS sessions +ORDER BY 1 DESC,2; + + + WITH states AS + ( + SELECT datname AS database, + COUNT(*) AS total, + COUNT(CASE WHEN state = 'active' THEN true END) AS active, + COUNT(CASE WHEN state = 'idle' THEN true END) AS idle, + COUNT(CASE WHEN state = 'idle in transaction' THEN true END) AS "idle in transaction", + COUNT(CASE WHEN state = 'idle in transaction (aborted)' THEN true END) AS "idle in transaction (aborted)", + COUNT(CASE WHEN state = 'fastpath function call' THEN true END) AS "fastpath function call", + COUNT(CASE WHEN state = 'disabled' THEN true END) AS disabled + FROM pg_stat_activity + GROUP BY database + ORDER BY database + ) + SELECT database, total, + active, + idle, + "idle in transaction", + "idle in transaction (aborted)", + "fastpath function call", + disabled + FROM states + UNION ALL + SELECT '$TOTAL', sum(total), + sum(active), + sum(idle), + sum("idle in transaction"), + sum("idle in transaction (aborted)"), + sum("fastpath function call"), + sum(disabled) + FROM states; + + + + + +-- +KIll Langläufer: + + +SELECT pg_terminate_backend(pid) + FROM pg_stat_activity + WHERE state = 'active' + AND pid <> pg_backend_pid() and clock_timestamp() - query_start > '15 minutes'::interval AND query like 'SELECT %'; SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + +-- + + + + SELECT pg_terminate_backend(pid) + FROM pg_stat_activity + WHERE state = 'active' + AND pid <> pg_backend_pid() and clock_timestamp() - query_start > '3 minutes'::interval AND query like 'SELECT %'; SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + + + +-- Kill lange wartende: + + SELECT string_agg(pid::text || '.log', ' ') + FROM pg_stat_activity + WHERE state = 'idle' + AND clock_timestamp() - backend_start > '15 minutes'::interval + AND clock_timestamp() - state_change > '5 minutes'::interval; SELECT pid, clock_timestamp() - backend_start AS "Zeit seit Start", clock_timestamp() - state_change AS "Zeit seit letztem Statement", query FROM pg_stat_activity WHERE state = 'idle' AND pid <> pg_backend_pid() AND clock_timestamp() - backend_start > '15 minutes'::interval AND clock_timestamp() - state_change > '5 minute'::interval ; SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + + + +SELECT * INTO TEMPORARY TABLE temp_analyse FROM ( + SELECT pid, + clock_timestamp() - backend_start AS "Zeit seit Start", + clock_timestamp() - state_change AS "Zeit seit letztem Statement", + state_change - backend_start AS "Zeit Start bis Haenger", + state --, + query + FROM pg_stat_activity + WHERE state IN ('idle', 'idle in transaction (aborted)') + AND pid <> pg_backend_pid() + AND clock_timestamp() - backend_start > '15 minutes'::interval + AND clock_timestamp() - state_change > '5 minute'::interval + ) AS tmp + -- + ; SELECT string_agg(pid::text || '.log', ' ') FROM temp_analyse; SELECT pg_terminate_backend(pid), * FROM temp_analyse; DROP TABLE temp_analyse; SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + + + + + + SELECT string_agg(pid::text || '.log', ' ') + FROM pg_stat_activity + WHERE state = 'idle' + AND clock_timestamp() - backend_start > '15 minutes'::interval + AND clock_timestamp() - state_change > '5 minutes'::interval; + + + SELECT pg_terminate_backend(pid) AS "Beendet", + pid, + datname, + state, + clock_timestamp() - backend_start AS "Zeit seit Start", + clock_timestamp() - state_change AS "Zeit seit letztem Statement", + state_change - backend_start, + query + FROM pg_stat_activity + WHERE state = 'idle in transaction (aborted)' + AND pid <> pg_backend_pid() + AND clock_timestamp() - backend_start > '15 minutes'::interval + AND clock_timestamp() - state_change > '5 minute'::interval ; + + SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + +\watch 30 + + + + +SELECT count(pg_terminate_backend(pid)), 'TERMINATED' as state + FROM pg_stat_activity + WHERE state = 'idle' + AND pid <> pg_backend_pid() and clock_timestamp() - backend_start > '15 minutes'::interval AND clock_timestamp() - state_change > '1 minute'::interval union all SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + + + +-- pg_terminate_backend(pid) + +SELECT pg_terminate_backend(pid) + FROM pg_stat_activity + WHERE state = 'idle' + AND pid <> pg_backend_pid() and clock_timestamp() - backend_start > '15 minutes'::interval AND clock_timestamp() - state_change > '20 minute'::interval; SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + + + + +-- IO Insgesamt: +-- Welche Tabellen mit ihren Indexen erzeigen am meisten IO? + + + SELECT schemaname || '."' || relname || '"' AS "Table", + heap_blks_read AS "Data IO", + heap_blks_hit AS "Data Cache", + idx_blks_read AS "Index IO", + idx_blks_hit AS "Index Cache", + round(CASE WHEN heap_blks_hit = 0 + THEN 0 + ELSE 100::numeric*heap_blks_hit::numeric/(heap_blks_read+heap_blks_hit) + END, + 2) AS "Data Hit Rate", + round(CASE WHEN idx_blks_hit = 0 + THEN 0 + ELSE 100::numeric*idx_blks_hit::numeric/(idx_blks_read+idx_blks_hit) + END, + 2) AS "Index Hit Rate", + pg_size_pretty(pg_table_size (schemaname || '."' || relname || '"')) AS "Data Size", + pg_size_pretty(pg_indexes_size(schemaname || '."' || relname || '"')) AS "Index Size", + ARRAY( SELECT indexrelname + FROM pg_stat_user_indexes i + WHERE idx_scan = 0 + AND i.schemaname = t.schemaname + AND i.relname = t.relname) AS "Ungenutzte Indexe" + FROM pg_statio_user_tables t + ORDER BY heap_blks_read+idx_blks_read DESC NULLS LAST; + + + +-- das gleiche, ohne "" beim Tabellenname: + + SELECT schemaname || '.' || relname AS "Table", + heap_blks_read AS "Data IO", + heap_blks_hit AS "Data Cache", + idx_blks_read AS "Index IO", + idx_blks_hit AS "Index Cache", + round(CASE WHEN heap_blks_hit = 0 + THEN 0 + ELSE 100::numeric*heap_blks_hit::numeric/(heap_blks_read+heap_blks_hit) + END, + 2) AS "Data Hit Rate", + round(CASE WHEN idx_blks_hit = 0 + THEN 0 + ELSE 100::numeric*idx_blks_hit::numeric/(idx_blks_read+idx_blks_hit) + END, + 2) AS "Index Hit Rate", + pg_size_pretty(pg_table_size (schemaname || '."' || relname || '"')) AS "Data Size", + pg_size_pretty(pg_indexes_size(schemaname || '."' || relname || '"')) AS "Index Size", + ARRAY( SELECT indexrelname + FROM pg_stat_user_indexes i + WHERE idx_scan = 0 + AND i.schemaname = t.schemaname + AND i.relname = t.relname) AS "Ungenutzte Indexe" + FROM pg_statio_user_tables t + ORDER BY heap_blks_read+idx_blks_read DESC NULLS LAST; + + + +-- +-- IO insgesamt schmaler +-- + +\t +select '

Ein paar kleine Statistiken für Daten und Indexe

'; + +select '

IO-Nutzung und ungenutzte Indexe (schmale Titel)

'; + +\t + + +\html + + + + SELECT relname AS "Table", + heap_blks_read AS "Dat IO", + heap_blks_hit AS "Dat Cache", + idx_blks_read AS "Idx IO", + idx_blks_hit AS "Idx Cache", + round(CASE WHEN heap_blks_hit = 0 + THEN 0 + ELSE 100::numeric*heap_blks_hit::numeric/(heap_blks_read+heap_blks_hit) + END, + 2) AS "DatHit%", + round(CASE WHEN idx_blks_hit = 0 + THEN 0 + ELSE 100::numeric*idx_blks_hit::numeric/(idx_blks_read+idx_blks_hit) + END, + 2) AS "IdxHit%", + pg_size_pretty(pg_table_size (schemaname || '."' || relname || '"')) AS "DatSize", + pg_size_pretty(pg_indexes_size(schemaname || '."' || relname || '"')) AS "IdxSize", + round( + CASE WHEN pg_table_size (schemaname || '."' || relname || '"') = 0 + THEN NULL + ELSE + pg_indexes_size(schemaname || '."' || relname || '"')::numeric / pg_table_size (schemaname || '."' || relname || '"'):: numeric + END, + 2 ) AS "IdxDat*", + array_to_string(ARRAY( SELECT indexrelname + FROM pg_stat_user_indexes i + WHERE idx_scan = 0 + AND i.schemaname = t.schemaname + AND i.relname = t.relname), E'\n') AS "Ungenutzte Indexe" + FROM pg_statio_user_tables t + ORDER BY heap_blks_read+idx_blks_read DESC NULLS LAST; + + + + + + + + + +-- Index IO: +-- Welche Indexe verursachen am meisten IO? + + +\t +SELECT '

Welche Indexe verursachen wie viel IO?

'; +\t +\html + + + SELECT io.schemaname || '.' || io.relname AS "Table", + io.indexrelname AS "Index Name", + idx_scan AS "#Idx-Scans", + idx_blks_read AS "Index IO", + idx_blks_hit AS "Index Cache", + round(CASE WHEN idx_blks_hit = 0 + THEN 0 + ELSE 100::numeric*idx_blks_hit/(idx_blks_read+idx_blks_hit) + END, + 2) AS "Hit Rate", + pg_size_pretty(pg_relation_size(io.schemaname || '."' || io.indexrelname || '"')) AS "Index Size" + FROM pg_statio_user_indexes io, pg_stat_user_indexes stat + WHERE io.schemaname = stat.schemaname + AND io.relname = stat.relname + AND io.indexrelname = stat.indexrelname + ORDER BY idx_blks_read DESC, + "Hit Rate" DESC, + pg_relation_size(io.schemaname || '."' || io.indexrelname || '"') DESC; + + + + +oder: +select *, pg_size_pretty( pg_relation_size(schemaname || '."' || indexrelname || '"') ) AS Indexsize from pg_stat_user_indexes order by pg_relation_size(schemaname || '."' || indexrelname || '"') desc; + + + + + + +-- Index/Data Bloat. + +-- Basis von https://wiki.postgresql.org/wiki/Show_database_bloat + + +\t +SELECT '

Data und Index-Bloat

'; + +\t +\html + + +SELECT + -- current_database(), schemaname, tablename, /*reltuples::bigint, relpages::bigint, otta,*/ + tablename || '.' || iname as "Index", /*ituples::bigint, ipages::bigint, iotta,*/ + ROUND((CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages::FLOAT/otta END)::NUMERIC,1) AS tbloat, + pg_size_pretty(CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::BIGINT END) AS wastedbytes, + ROUND((CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages::FLOAT/iotta END)::NUMERIC,1) AS ibloat, + pg_size_pretty( CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta)::bigint END) AS wastedibytes FROM ( + SELECT + schemaname, tablename, cc.reltuples, cc.relpages, bs, + CEIL((cc.reltuples*((datahdr+ma- + (CASE WHEN datahdr%ma=0 THEN ma ELSE datahdr%ma END))+nullhdr2+4))/(bs-20::FLOAT)) AS otta, + COALESCE(c2.relname,'?') AS iname, COALESCE(c2.reltuples,0) AS ituples, COALESCE(c2.relpages,0) AS ipages, + COALESCE(CEIL((c2.reltuples*(datahdr-12))/(bs-20::FLOAT)),0) AS iotta -- very rough approximation, assumes all cols + FROM ( + SELECT + ma,bs,schemaname,tablename, + (datawidth+(hdr+ma-(CASE WHEN hdr%ma=0 THEN ma ELSE hdr%ma END)))::NUMERIC AS datahdr, + (maxfracsum*(nullhdr+ma-(CASE WHEN nullhdr%ma=0 THEN ma ELSE nullhdr%ma END))) AS nullhdr2 + FROM ( + SELECT + schemaname, tablename, hdr, ma, bs, + SUM((1-null_frac)*avg_width) AS datawidth, + MAX(null_frac) AS maxfracsum, + hdr+( + SELECT 1+COUNT(*)/8 + FROM pg_stats s2 + WHERE null_frac<>0 AND s2.schemaname = s.schemaname AND s2.tablename = s.tablename + ) AS nullhdr + FROM pg_stats s, ( + SELECT + (SELECT current_setting('block_size')::NUMERIC) AS bs, + CASE WHEN SUBSTRING(v,12,3) IN ('8.0','8.1','8.2') THEN 27 ELSE 23 END AS hdr, + CASE WHEN v ~ 'mingw32' THEN 8 ELSE 4 END AS ma + FROM (SELECT version() AS v) AS foo + ) AS constants + GROUP BY 1,2,3,4,5 + ) AS foo + ) AS rs + JOIN pg_class cc ON cc.relname = rs.tablename + JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = rs.schemaname AND nn.nspname <> 'information_schema' + LEFT JOIN pg_index i ON indrelid = cc.oid + LEFT JOIN pg_class c2 ON c2.oid = i.indexrelid) AS sml + ORDER BY (CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::BIGINT END) + + CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta)::bigint END + DESC +; + + + + + +-- Auf einem Slave: wie ist denn die Latenz, wo steht er im Replay? + + SELECT now()::time, + pg_last_xlog_receive_location() AS "Receive Location", + pg_last_xlog_replay_location() AS "Replay Location", + clock_timestamp() - pg_last_xact_replay_timestamp() AS "Last Replay Lag"; + + + + + SELECT now()::time, + pg_last_xlog_receive_location() AS "Receive Location", + pg_last_xlog_replay_location() AS "Replay Location", + -(pg_last_xact_replay_timestamp() - clock_timestamp()) AS "Last Replay Lag"; + + +-- mit repmgrd: + + + SELECT now()::time, + pg_last_xlog_receive_location() AS "Receive Location", + pg_last_xlog_replay_location() AS "Replay Location", + now() - pg_last_xact_replay_timestamp() AS "Last Replay Lag", + time_lag AS "repmgrd Lag" + FROM repmgr_cluster1.repl_status; + + + now | Receive Location | Replay Location | Last Replay Lag | repmgrd Lag +-----------------+------------------+-----------------+-----------------+----------------- + 11:53:04.998122 | D1/AE82B650 | D1/AE6C3478 | 00:01:04.949325 | 00:01:04.960063 +(1 row) + now | Receive Location | Replay Location | Last Replay Lag | repmgrd Lag +-----------------+------------------+-----------------+-----------------+----------------- + 11:53:04.998122 | D1/AE82B650 | D1/AE6C3478 | 00:01:04.949325 | 00:01:04.960063 +(1 row) + + + + + + + + + + + + + +--------------------------------------------------------- + + + + + + + + +# pgBadger Logging: +log_destination = 'stderr' +logging_collector = on +log_directory = 'pg_log' +log_filename = 'postgresql-%Y-%m-%d.log' + +log_min_duration_statement = 0 +log_line_prefix = '%t [%p]: [%l-1] user=%u,db=%d ' + +log_checkpoints = on +log_connections = on +log_disconnections = on +log_lock_waits = on +log_temp_files = 0 + + +lc_messages='C' + + + +---------------------------- + + + + +------------------------------------------------------------------------------ + + +weiteres ... teilweise kaputt + + + +********************************************************************************************************** +********************************************************************************************************** + + + + +-- Lock-Analyse: + +SELECT locktype, + (SELECT datname FROM pg_database db WHERE db.oid = l.database) AS database, + (SELECT relname FROM pg_class c WHERE c.oid = l.relation) AS relation, + page, + tuple, + virtualxid, + transactionid, + (SELECT relname FROM pg_class c WHERE c.oid = l.classid) AS targert_relname, + objid, + objsubid, + virtualtransaction, + l.pid, + clock_timestamp() - xact_start AS "Trans Dauer", + clock_timestamp() - query_start AS "Query Dauer", + query, waiting, + mode, + granted, + fastpath + FROM pg_locks l + LEFT JOIN pg_stat_activity a ON a.pid = l.pid; + + + + + + + + + + + +-- Locks +-- 09.1 + + SELECT procpid, usename, application_name, client_addr, datname, clock_timestamp() - xact_start AS "Trans.Dauer", + clock_timestamp() - query_start AS "Query Dauer", + current_query, mode, granted, locktype, waiting + FROM pg_stat_activity, pg_locks + WHERE pid = procpid + AND procpid <> pg_backend_pid() + ORDER BY "Query Dauer" DESC; + + + +-- 9.2, NUR waiting + + + SELECT a.pid, usename, application_name, client_addr, datname, statement_timestamp() - xact_start AS "Trans.Dauer", + statement_timestamp() - query_start AS "Query Dauer", + query, mode, granted, locktype, waiting + FROM pg_stat_activity a, pg_locks l + WHERE a.pid = l.pid + AND a.pid <> pg_backend_pid() and waiting + ORDER BY "Query Dauer" DESC; + + + + + SELECT a.pid, datname, clock_timestamp() - xact_start AS "Trans.Dauer", + clock_timestamp() - query_start AS "Query Dauer", + query, mode, granted, locktype, waiting + FROM pg_stat_activity a, pg_locks l + WHERE a.pid = l.pid + AND a.pid <> pg_backend_pid() + ORDER BY "Query Dauer" DESC; + + + + SELECT bl.pid AS blocked_pid, a.usename AS blocked_user, + kl.pid AS blocking_pid, ka.usename AS blocking_user, + a.query AS blocked_query, ka.query AS blocking_query, + now() - a.query_start AS blocked_duration, + now() - ka.query_start AS blocking_duration + FROM pg_catalog.pg_locks bl + JOIN pg_catalog.pg_stat_activity a + ON bl.pid = a.pid + JOIN pg_catalog.pg_locks kl + JOIN pg_catalog.pg_stat_activity ka + ON kl.pid = ka.pid + ON bl.transactionid = kl.transactionid AND bl.pid != kl.pid + WHERE NOT bl.granted; + + + + + SELECT now(), bl.pid AS blocked_pid, kl.pid AS blocking_pid, + now() - a.query_start AS blocked_duration, + now() - ka.query_start AS blocking_duration, + a.query AS blocked_query, ka.state AS blocking_proc_state, ka.query AS query_at_blocking_proc + FROM pg_catalog.pg_locks bl + JOIN pg_catalog.pg_stat_activity a + ON bl.pid = a.pid + JOIN pg_catalog.pg_locks kl + JOIN pg_catalog.pg_stat_activity ka + ON kl.pid = ka.pid + ON bl.transactionid = kl.transactionid AND bl.pid != kl.pid + WHERE NOT bl.granted; + + +-------- + + + +WITH RECURSIVE + c(requested, current) AS + ( VALUES + ('AccessShareLock'::text, 'AccessExclusiveLock'::text), + ('RowShareLock'::text, 'ExclusiveLock'::text), + ('RowShareLock'::text, 'AccessExclusiveLock'::text), + ('RowExclusiveLock'::text, 'ShareLock'::text), + ('RowExclusiveLock'::text, 'ShareRowExclusiveLock'::text), + ('RowExclusiveLock'::text, 'ExclusiveLock'::text), + ('RowExclusiveLock'::text, 'AccessExclusiveLock'::text), + ('ShareUpdateExclusiveLock'::text, 'ShareUpdateExclusiveLock'::text), + ('ShareUpdateExclusiveLock'::text, 'ShareLock'::text), + ('ShareUpdateExclusiveLock'::text, 'ShareRowExclusiveLock'::text), + ('ShareUpdateExclusiveLock'::text, 'ExclusiveLock'::text), + ('ShareUpdateExclusiveLock'::text, 'AccessExclusiveLock'::text), + ('ShareLock'::text, 'RowExclusiveLock'::text), + ('ShareLock'::text, 'ShareUpdateExclusiveLock'::text), + ('ShareLock'::text, 'ShareRowExclusiveLock'::text), + ('ShareLock'::text, 'ExclusiveLock'::text), + ('ShareLock'::text, 'AccessExclusiveLock'::text), + ('ShareRowExclusiveLock'::text, 'RowExclusiveLock'::text), + ('ShareRowExclusiveLock'::text, 'ShareUpdateExclusiveLock'::text), + ('ShareRowExclusiveLock'::text, 'ShareLock'::text), + ('ShareRowExclusiveLock'::text, 'ShareRowExclusiveLock'::text), + ('ShareRowExclusiveLock'::text, 'ExclusiveLock'::text), + ('ShareRowExclusiveLock'::text, 'AccessExclusiveLock'::text), + ('ExclusiveLock'::text, 'RowShareLock'::text), + ('ExclusiveLock'::text, 'RowExclusiveLock'::text), + ('ExclusiveLock'::text, 'ShareUpdateExclusiveLock'::text), + ('ExclusiveLock'::text, 'ShareLock'::text), + ('ExclusiveLock'::text, 'ShareRowExclusiveLock'::text), + ('ExclusiveLock'::text, 'ExclusiveLock'::text), + ('ExclusiveLock'::text, 'AccessExclusiveLock'::text), + ('AccessExclusiveLock'::text, 'AccessShareLock'::text), + ('AccessExclusiveLock'::text, 'RowShareLock'::text), + ('AccessExclusiveLock'::text, 'RowExclusiveLock'::text), + ('AccessExclusiveLock'::text, 'ShareUpdateExclusiveLock'::text), + ('AccessExclusiveLock'::text, 'ShareLock'::text), + ('AccessExclusiveLock'::text, 'ShareRowExclusiveLock'::text), + ('AccessExclusiveLock'::text, 'ExclusiveLock'::text), + ('AccessExclusiveLock'::text, 'AccessExclusiveLock'::text) + ), + l AS + ( + SELECT + (locktype,DATABASE,relation::regclass::text,page,tuple,virtualxid,transactionid,classid,objid,objsubid) AS target, + virtualtransaction, + pid, + mode, + granted + FROM pg_catalog.pg_locks + ), + t AS + ( + SELECT + blocker.target AS blocker_target, + blocker.pid AS blocker_pid, + blocker.mode AS blocker_mode, + '1'::int AS depth, + blocked.target AS target, + blocked.pid AS pid, + blocked.mode AS mode, + blocker.pid::text || ',' || blocked.pid::text AS seq + FROM l blocker + JOIN l blocked + ON ( NOT blocked.granted + AND blocked.pid != blocker.pid + AND blocked.target IS NOT DISTINCT FROM blocker.target) + JOIN c ON (c.requested = blocked.mode AND c.current = blocker.mode) + UNION ALL + SELECT + blocker.target, + blocker.pid, + blocker.mode, + depth + 1, + blocked.target, + blocked.pid, + blocked.mode, + blocker.seq || ',' || blocked.pid::text + FROM t blocker + JOIN l blocked + ON ( NOT blocked.granted + AND blocked.pid != blocker.pid + AND blocked.target IS NOT DISTINCT FROM blocker.target) + JOIN c ON (c.requested = blocked.mode AND c.current = blocker.mode) + WHERE depth < 1200 + ) + SELECT target, blocker_pid, blocker_mode, depth, t.pid AS blocked_pid, mode AS blocked_mode, seq, + a_blocked.client_addr AS blocked_client, now() - a_blocked.xact_start AS blocked_trans_time, now() - a_blocked.query_start AS blocked_query_time, a_blocked.state AS blocked_state, a_blocked.query AS blocked_query, + a_blocker.client_addr AS blocker_client, now() - a_blocker.xact_start AS blocker_trans_time, now() - a_blocker.query_start AS blocker_query_time, a_blocker.state AS blocker_state, a_blocker.query AS blocker_last_query + + FROM t + LEFT JOIN pg_stat_activity a_blocker ON blocker_pid = a_blocker.pid + LEFT JOIN pg_stat_activity a_blocked ON t.pid = a_blocked.pid + ORDER BY seq; + + + + +-- +-- Langläufer-Queries +-- + + SELECT clock_timestamp() - xact_start AS "Trans.Dauer", + clock_timestamp() - query_start AS "Query Dauer", + usename, + state, + query + FROM pg_stat_activity + WHERE state IN ('active', 'idle_in_intransaction') + AND pid <> pg_backend_pid() + AND clock_timestamp() - xact_start > '1 second' + ORDER BY "Query Dauer" DESC; + + + + +-- Wie viele Verbindungen sind offen und werden wie genutzt? + +SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + +denic=# SELECT count(*), state FROM pg_stat_activity group by state ORDER BY state; + count | state +-------+--------------------- + 12 | active + 1254 | idle + 3 | idle in transaction +(3 rows) + + + +-- Auf einem Slave: wie ist denn die Latenz, wo steht er im Replay? + + + SELECT now()::time, + pg_last_xlog_receive_location() AS "Receive Location", + pg_last_xlog_replay_location() AS "Replay Location", + now() - pg_last_xact_replay_timestamp() AS "Last Replay Lag", + time_lag AS "repmgrd Lag" + FROM repmgr_cluster1.repl_status; + + + now | Receive Location | Replay Location | Last Replay Lag | repmgrd Lag +-----------------+------------------+-----------------+-----------------+----------------- + 11:53:04.998122 | D1/AE82B650 | D1/AE6C3478 | 00:01:04.949325 | 00:01:04.960063 +(1 row) + + + +-- ohne repmgrd: + + SELECT now()::time, + pg_last_xlog_receive_location() AS "Receive Location", + pg_last_xlog_replay_location() AS "Replay Location", + now() - pg_last_xact_replay_timestamp() AS "Last Replay Lag"; + + + + + +-- BVerhältnis sqeuentielle Scans zu Index-Scans +SELECT relname, +CASE WHEN idx_scan <> 0 THEN round(seq_scan::numeric/idx_scan::numeric, 10)::text + ELSE 'no idx scan!' + END +AS idx_seq_ratio, seq_scan, seq_tup_read, idx_scan, idx_tup_fetch, n_tup_ins, n_tup_upd, n_tup_del, n_tup_hot_upd, n_live_tup, n_dead_tup FROM pg_stat_user_tables ORDER BY seq_tup_read DESC, relname; + + + + + + +-- +-- Extra-Funktionen fürs Monitoring +-- Um ohne Super-User-Rechte System-Werte auslesen zu können. +-- +-- + + +-- +-- Zählen nur der aktiven Connections +-- + +CREATE OR REPLACE FUNCTION monitor_count_active_connections() RETURNS BIGINT + SECURITY DEFINER + SET search_path TO public, pg_temp + LANGUAGE sql + AS + $code$ + SELECT count(*) AS count FROM pg_stat_activity WHERE state = 'active'; + $code$; + + +-- +-- Zählen der aktiven/Idle Verbindungen +-- Ein klein wenig aufwendiger, um nur einmal pg_stat_activity abzufragen +-- Drei mal SELECT count(*) FROM pg_stat_activity WHERE status = 'xx' wäre einfacher +-- + +CREATE OR REPLACE FUNCTION monitor_count_connections(OUT active INTEGER, OUT idle INTEGER, OUT idle_in_transaction INTEGER) + SECURITY DEFINER + SET search_path TO public, pg_temp + LANGUAGE plpgsql + AS + $code$ + DECLARE + row RECORD; + BEGIN + FOR row IN SELECT count(*) AS count, state FROM pg_stat_activity GROUP BY state LOOP + CASE row.state + WHEN 'active' THEN + active := row.count; + WHEN 'idle' THEN + idle := row.count; + WHEN 'idle in transaction' THEN + idle_in_transaction := row.count; + END CASE; + END LOOP; + + END + $code$; + + +-- +-- Funktion zum leeren der alten Daten aus der repmgrd-Überwachung. +-- + +CREATE OR REPLACE FUNCTION repmgr_cluster1.delete_old_monitoring_entries () RETURNS void AS + $BODY$ + BEGIN + DELETE FROM repmgr_cluster1.repl_monitor WHERE last_monitor_time < now() - interval '8 days'; + END; + $BODY$ + LANGUAGE 'plpgsql'; + + + +\echo SQL-File OK! + + + + + + +CREATE TABLE activity_log + ( + time timestamp with time zone NOT NULL DEFAULT now() PRIMARY KEY, + active SMALLINT NOT NULL, + idle SMALLINT NOT NULL, + idle_in_transaction SMALLINT NOT NULL, + waiting SMALLINT NOT NULL, + max_age_transaction INTERVAL, + max_age_query INTERVAL, + queries TEXT[], + waiting_queries TEXT[] + ); + + + +INSERT INTO activity_log (active, idle, idle_in_transaction, queries) + SELECT COUNT(CASE WHEN state = 'active' THEN 1 END ), + COUNT(CASE WHEN state = 'idle' THEN 1 END ), + COUNT(CASE WHEN state = 'idle in transaction' THEN 1 END ), + ARRAY(SELECT query FROM pg_stat_activity WHERE state = 'active') + FROM pg_stat_activity + ; + +WITH activity AS (SELECT datname, xact_start, query_start, state, waiting, query FROM pg_stat_activity WHERE pid <> pg_backend_pid() ) +INSERT INTO activity_log (active, idle, idle_in_transaction, waiting, max_age_transaction, max_age_query, queries, waiting_queries) + SELECT COUNT(CASE WHEN state = 'active' THEN 1 END ), + COUNT(CASE WHEN state = 'idle' THEN 1 END ), + COUNT(CASE WHEN state = 'idle in transaction' THEN 1 END ), + COUNT(CASE WHEN waiting THEN 1 END ), + now() - MIN(xact_start), + (SELECT now() - MIN(query_start) FROM activity WHERE state = 'active'), + ARRAY(SELECT datname || ': ' || query FROM activity WHERE state = 'active'), + ARRAY(SELECT datname || ': ' || query FROM activity WHERE waiting) + FROM activity + ; + + +select * from activity_log a1 where queries::text like '%SELECT type_id FROM art_resource%' and queries::text not like '%activity_log%' and max_age_query > '10 seconds' and (select queries::text from activity_log a2 where a2.time < a1.time order by time desc limit 1) like '%SELECT type_id FROM art_resource%' order by time desc limit 10; + + +select time, active, idle, idle_in_transaction AS iit, waiting, max_age_transaction, max_age_query FROM activity_log order by time desc limit 10000; + + + + + + + + + + + + + +#!/bin/bash +# Get current swap usage for all running processes +# Erik Ljungstrom 27/05/2011 +SUM=0 +OVERALL=0 +for DIR in `find /proc/ -maxdepth 1 -type d | egrep "^/proc/[0-9]"` ; do + PID=`echo $DIR | cut -d / -f 3` + PROGNAME=`ps -p $PID -o comm --no-headers` + for SWAP in `grep Swap $DIR/smaps 2>/dev/null| awk '{ print $2 }'` + do + let SUM=$SUM+$SWAP + done + echo "PID=$PID - Swap used: $SUM - ($PROGNAME )" + let OVERALL=$OVERALL+$SUM + SUM=0 + +done +echo "Overall swap used: $OVERALL" +