Re: PostgreSQL(v9.6.5) not releasing old/inactive IDLE connections

From: hubert depesz lubaczewski <depesz(at)depesz(dot)com>
To: Ron <ronljohnsonjr(at)gmail(dot)com>
Cc: pgsql-admin(at)lists(dot)postgresql(dot)org
Subject: Re: PostgreSQL(v9.6.5) not releasing old/inactive IDLE connections
Date: 2021-12-08 12:23:16
Message-ID: 20211208122316.GB28627@depesz.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: 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

In response to

Browse pgsql-admin by date

  From Date Subject
Next Message Mladen Gogala 2021-12-08 14:11:38 Re: AW: postgresql long running query
Previous Message Thomas Kellerer 2021-12-08 11:24:46 Re: PostgreSQL(v9.6.5) not releasing old/inactive IDLE connections