This article is half-done without your Comment! *** Please share your thoughts via Comment ***
In this post, I am sharing a UDF and using this non-super user can kill their queries.
As a PostgreSQL DBA, You may find long running queries or IDLE queries of the user. Many times users also disturb to DBA for killing their queries.
In my organisation, we created one function and assigned to all users so that they can kill their queries without disturbing to DBA team.
This function created such a way that, a user can kill their own queries only. They can find process_id of other users, but they can’t kill other queries.
Below is a full demonstration of this:
Create a schema:
1 |
CREATE SCHEMA query_admin; |
Create a function to kill user query:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 |
CREATE OR REPLACE FUNCTION query_admin.kill_process(userpid integer) RETURNS boolean AS $body$ DECLARE qry boolean; BEGIN qry := (SELECT pg_catalog.pg_cancel_backend(pid) FROM pg_stat_activity WHERE usename=(select session_user) AND pid=userpid); RETURN qry; END; $body$ LANGUAGE plpgsql SECURITY DEFINER VOLATILE RETURNS NULL ON NULL INPUT; |
Grant permission to Public so that all user can access this:
1 2 |
GRANT USAGE ON SCHEMA query_admin TO public; GRANT EXECUTE ON FUNCTION query_admin.kill_process(pid integer) TO public; |
User can check their running process_id queries using below query:
1 2 |
SELECT * FROM pg_stat_activity WHERE usename = 'user_name'; |
Sample execution of kill_process():
1 2 |
SELECT *FROM query_admin.kill_process(process_id); SELECT *FROM query_admin.kill_process(14526); |
Leave a Reply