Re: PostgreSQL(v9.6.5) not releasing old/inactive IDLE connections - Mailing list pgsql-admin

From hubert depesz lubaczewski
Subject Re: PostgreSQL(v9.6.5) not releasing old/inactive IDLE connections
Date
Msg-id 20211208122316.GB28627@depesz.com
Whole thread Raw
In response to Re: PostgreSQL(v9.6.5) not releasing old/inactive IDLE connections  (Ron <ronljohnsonjr@gmail.com>)
List pgsql-admin
On Wed, Dec 08, 2021 at 01:23:32AM -0600, Ron wrote:
> I set up a cron job that regularly kills old idle connections.
> SELECT pg_terminate_backend(pid)
> FROM pg_stat_activity
> WHERE datname = 'databasename'
>   AND pid <> pg_backend_pid()
>   AND state = 'idle'
>   and extract(epoch from (current_timestamp - query_start)) > 20*60 -- 20
> minutes
> ;

Two notes:
1. it's better to use state_change and not query_start. For example, if
   I'd start 2 hours query, 3 hours ago, then "now" it would still have
   query_start at (now() - 3 hours), despite the fact that it would be
   idle only for 1 hour.
2. doing calculations in epoch is bad idea. it can become your muscle
   memory, and it will cause problems with indexing. instead:
       and state_change < current_timestamp - '20 minutes'::interval

depesz



pgsql-admin by date:

Previous
From: Thomas Kellerer
Date:
Subject: Re: PostgreSQL(v9.6.5) not releasing old/inactive IDLE connections
Next
From: Mladen Gogala
Date:
Subject: Re: AW: postgresql long running query