Skip to content

Commit

Permalink
feat: recommend to terminate over cancelling blocking queries
Browse files Browse the repository at this point in the history
  • Loading branch information
dcupif committed May 21, 2024
1 parent 0aff185 commit 2c6b133
Show file tree
Hide file tree
Showing 3 changed files with 27 additions and 17 deletions.
8 changes: 5 additions & 3 deletions content/runbooks/postgresql/PostgreSQLLongRunningQueries.md
Original file line number Diff line number Diff line change
Expand Up @@ -32,11 +32,13 @@ Alert is triggered when SQL queries run for an extended period.
{{% sql "../postgresql/sql/list-long-running-transactions.sql" %}}
{{< /details >}}

1. Cancel the queries
Queries could be blocked in trying to acquire a lock, so pay particular attention at the `blocked_by` column. If you identify specific queries blocking others, note down their PIDs. Below is a focused view of current locks on the database:

{{% sql "sql/cancel_backend.sql" %}}
{{< details title="SQL" open=false >}}
{{% sql "../postgresql/sql/list-ongoing-locks.sql" %}}
{{< /details >}}

1. If queries do not get cancelled, kill them
1. Terminate in priority the blocking queries, if not enough, terminate the other long running queries

{{% sql "sql/terminate_backend.sql" %}}

Expand Down
14 changes: 0 additions & 14 deletions content/runbooks/postgresql/sql/cancel_backend.sql

This file was deleted.

22 changes: 22 additions & 0 deletions content/runbooks/postgresql/sql/list-ongoing-locks.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
SELECT
blocked_locks.pid AS blocked_pid,
blocked_activity.usename AS blocked_user,
blocking_locks.pid AS blocking_pid,
blocking_activity.usename AS blocking_user,
blocked_activity.query AS blocked_statement,
blocking_activity.query AS current_statement_in_blocking_process
FROM pg_catalog.pg_locks blocked_locks
JOIN pg_catalog.pg_stat_activity blocked_activity ON blocked_activity.pid = blocked_locks.pid
JOIN pg_catalog.pg_locks blocking_locks ON blocking_locks.locktype = blocked_locks.locktype
AND blocking_locks.database IS NOT DISTINCT FROM blocked_locks.database
AND blocking_locks.relation IS NOT DISTINCT FROM blocked_locks.relation
AND blocking_locks.page IS NOT DISTINCT FROM blocked_locks.page
AND blocking_locks.tuple IS NOT DISTINCT FROM blocked_locks.tuple
AND blocking_locks.virtualxid IS NOT DISTINCT FROM blocked_locks.virtualxid
AND blocking_locks.transactionid IS NOT DISTINCT FROM blocked_locks.transactionid
AND blocking_locks.classid IS NOT DISTINCT FROM blocked_locks.classid
AND blocking_locks.objid IS NOT DISTINCT FROM blocked_locks.objid
AND blocking_locks.objsubid IS NOT DISTINCT FROM blocked_locks.objsubid
AND blocking_locks.pid != blocked_locks.pid
JOIN pg_catalog.pg_stat_activity blocking_activity ON blocking_activity.pid = blocking_locks.pid
WHERE NOT blocked_locks.granted;

0 comments on commit 2c6b133

Please sign in to comment.