|
| 1 | +\c pg_features_demo |
| 2 | +SET ROLE TO demorole; |
| 3 | + |
| 4 | +/* |
| 5 | +
|
| 6 | +Sometimes it is necessary to "shoot down" some own runaway queries from other users. To do that nicely from within SQL ( |
| 7 | +technically possible also via the OS actually) there are 2 options: |
| 8 | +
|
| 9 | + * pg_cancel_backend - the nice way. Only the query gets canceled. Available for all users for their own queries. |
| 10 | + * pg_terminate_backend - the hard way. User session is "kicked" from the server and needs to authenticate again. Needs |
| 11 | + superuser rights or starting from v10 also possible with the "pg_signal_backend" GRANT. |
| 12 | +
|
| 13 | +*/ |
| 14 | + |
| 15 | +-- cancel all of your own queries from other sessions / tools |
| 16 | +SELECT pg_cancel_backend(pid) |
| 17 | +FROM pg_stat_activity |
| 18 | +WHERE usename = CURRENT_USER |
| 19 | +AND pid != pg_backend_pid(); -- always leave out our newly executing query-- cancel all of your own queries from other sessions / tools |
| 20 | + |
| 21 | +-- cancel own active queries that are running for more than 5min |
| 22 | +SELECT pg_cancel_backend(pid) |
| 23 | +FROM pg_stat_activity |
| 24 | +WHERE usename = CURRENT_USER |
| 25 | +AND state != 'idle' |
| 26 | +AND now() - query_start > '5min'::interval; |
| 27 | + |
| 28 | +/* |
| 29 | +Note though that the best way to guard against your own "runaway" queries is to set appropriate timeouts: |
| 30 | +*/ |
| 31 | +SET statement_timeout TO '30s'; -- effective immediately |
| 32 | +ALTER ROLE demorole IN DATABASE pg_features_demo SET statement_timeout TO '1min'; -- effective on next session |
| 33 | + |
| 34 | +-- NB! When using SET ROLE then it might be a good idea to check who you currently "are" with: |
| 35 | +SELECT CURRENT_USER, SESSION_USER; -- SET ROLE alters CURRENT_USER ! |
| 36 | + |
| 37 | + |
| 38 | +-- terminate all users that are "idling" inside of a transaction |
| 39 | +SELECT pg_terminate_backend(pid) |
| 40 | +FROM pg_stat_activity |
| 41 | +WHERE datname = current_database() -- only users from "our" DB |
| 42 | + AND state = 'idle in transaction' |
| 43 | + AND pid != pg_backend_pid(); -- always leave out our newly executing query |
0 commit comments