Skip to content

Commit 9f2b55d

Browse files
author
Josh Berkus
committed
Added kill_idle stored procedures.
1 parent 9e4fffc commit 9f2b55d

File tree

3 files changed

+98
-0
lines changed

3 files changed

+98
-0
lines changed

README.md

Lines changed: 13 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2,3 +2,16 @@ pgx_scripts
22
===========
33

44
A collection of useful little scripts for database analysis and administration, created by our team at PostgreSQL Experts.
5+
6+
administration
7+
==============
8+
9+
kill_idle_91.sql
10+
----------------
11+
12+
A stored procedure which kills idle transactions on PostgreSQL versions 8.3 to 9.1. Intended to be called by a cron job. Takes idle time, polling time, and exempted user list parameters. Outputs pipe-delimited text with the data about the sessions killed.
13+
14+
kill_idle_93.sql
15+
----------------
16+
17+
A stored procedure which kills idle transactions on PostgreSQL versions 9.2 and later. Intended to be called by a cron job. Takes idle time and exempted user list parameters. Outputs JSON with the data about the sessions killed.

administration/kill_idle_91.sql

Lines changed: 47 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,47 @@
1+
create or replace function kill_idle_transactions_91 (
2+
timelimit INTERVAL DEFAULT '10 minutes',
3+
safe_users TEXT[] DEFAULT '{}',
4+
wait_time INT DEFAULT 10)
5+
returns SETOF text
6+
language plpgsql
7+
as
8+
$f$
9+
declare idles INT[];
10+
cancelled RECORD;
11+
output TEXT;
12+
13+
begin
14+
15+
SELECT array_agg(procpid)
16+
INTO idles
17+
FROM pg_stat_activity
18+
WHERE current_query = '<IDLE> in transaction'
19+
AND ( now() - xact_start ) > timelimit
20+
AND ( usename != ANY(safe_users)
21+
OR safe_users = '{}' );
22+
23+
IF idles IS NULL THEN
24+
RETURN;
25+
END IF;
26+
27+
PERFORM pg_sleep(wait_time);
28+
29+
FOR cancelled IN
30+
SELECT pg_stat_activity.*, pg_terminate_backend(procpid)
31+
FROM pg_stat_activity
32+
WHERE procpid = ANY ( idles )
33+
AND current_query = '<IDLE> in transaction' LOOP
34+
35+
output := array_to_string(ARRAY[ now()::TEXT,
36+
cancelled.datname::TEXT, cancelled.procpid::TEXT, cancelled.usename::TEXT,
37+
cancelled.application_name, cancelled.client_addr::TEXT,
38+
cancelled.backend_start::TEXT, cancelled.xact_start::TEXT,
39+
cancelled.waiting::TEXT], '|');
40+
41+
RETURN NEXT output;
42+
43+
END LOOP;
44+
45+
RETURN;
46+
47+
end; $f$;

administration/kill_idle_93.sql

Lines changed: 38 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,38 @@
1+
create or replace function kill_idle_transactions (
2+
timelimit INTERVAL DEFAULT '10 minutes',
3+
safe_users TEXT[] DEFAULT '{}')
4+
returns SETOF json
5+
language plpgsql
6+
as
7+
$f$
8+
declare
9+
cancelled JSON;
10+
11+
begin
12+
13+
FOR cancelled IN
14+
WITH terminated AS (
15+
SELECT pg_stat_activity.*, pg_terminate_backend(pid)
16+
FROM pg_stat_activity
17+
WHERE state = 'idle in transaction'
18+
AND (now() - state_change) > timelimit
19+
AND ( usename != ANY(safe_users)
20+
OR safe_users = '{}' )),
21+
termformat AS (
22+
SELECT now() as killtime,
23+
datname, pid, usename, application_name,
24+
client_addr, backend_start, xact_start,
25+
state_change, waiting, "query"
26+
FROM terminated )
27+
SELECT row_to_json(termformat.*)
28+
FROM termformat
29+
LOOP
30+
31+
RETURN NEXT cancelled;
32+
33+
END LOOP;
34+
35+
RETURN;
36+
37+
end; $f$;
38+

0 commit comments

Comments
 (0)