-
Notifications
You must be signed in to change notification settings - Fork 10
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #5 from keithf4/v0.3
v0.3 Add support for command functions to control pgBouncer administration
- Loading branch information
Showing
7 changed files
with
284 additions
and
5 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,3 +1,7 @@ | ||
v0.3 | ||
-- Add command functions to allow running pgBouncer commands on the target server. Note that the role defined in the user mapping must be given admin access to the pgBouncer admin console. It is recommended to have separate roles in the PostgreSQL database to allow there to be separate user mappings: one for simple monitoring and another for admin console access. | ||
|
||
|
||
v0.2 | ||
|
||
-- Add "pgbouncer_" prefix to all object names to help avoid naming collisions with commonly named objects. Now no longer generally necessary to install in dedicated schema, but still recommended if possible. |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,4 +1,4 @@ | ||
default_version = '0.2' | ||
comment = 'Extension for querying pgbouncer stats from normal SQL views' | ||
default_version = '0.3' | ||
comment = 'Extension for querying pgbouncer stats from normal SQL views & running pgbouncer commands from normal SQL functions' | ||
requires = dblink | ||
relocatable = false |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,121 @@ | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_disable(p_dbname text) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
PERFORM dblink_exec('pgbouncer', format('DISABLE %I', p_dbname)); | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_enable(p_dbname text) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
PERFORM dblink_exec('pgbouncer', format('ENABLE %I', p_dbname)); | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_kill(p_dbname text DEFAULT NULL) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
IF p_dbname IS NULL THEN | ||
PERFORM dblink_exec('pgbouncer', 'KILL'); | ||
ELSE | ||
PERFORM dblink_exec('pgbouncer', format('KILL %I', p_dbname)); | ||
END IF; | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_pause(p_dbname text DEFAULT NULL) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
IF p_dbname IS NULL THEN | ||
PERFORM dblink_exec('pgbouncer', 'PAUSE'); | ||
ELSE | ||
PERFORM dblink_exec('pgbouncer', format('PAUSE %I', p_dbname)); | ||
END IF; | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_reconnect(p_dbname text DEFAULT NULL) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
IF p_dbname IS NULL THEN | ||
PERFORM dblink_exec('pgbouncer', 'RECONNECT'); | ||
ELSE | ||
PERFORM dblink_exec('pgbouncer', format('RECONNECT %I', p_dbname)); | ||
END IF; | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_reload() RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
PERFORM dblink_exec('pgbouncer', 'RELOAD'); | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_resume(p_dbname text DEFAULT NULL) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
IF p_dbname IS NULL THEN | ||
PERFORM dblink_exec('pgbouncer', 'RESUME'); | ||
ELSE | ||
PERFORM dblink_exec('pgbouncer', format('RESUME %I', p_dbname)); | ||
END IF; | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_set(p_name text, p_value text) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
PERFORM dblink_exec('pgbouncer', format('SET %s = %L', p_name, p_value)); | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_shutdown() RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
PERFORM dblink_exec('pgbouncer', 'shutdown'); | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_suspend() RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
PERFORM dblink_exec('pgbouncer', 'SUSPEND'); | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_wait_close(p_dbname text DEFAULT NULL) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
IF p_dbname IS NULL THEN | ||
PERFORM dblink_exec('pgbouncer', 'WAIT_CLOSE'); | ||
ELSE | ||
PERFORM dblink_exec('pgbouncer', format('WAIT_CLOSE %I', p_dbname)); | ||
END IF; | ||
END | ||
$$; | ||
|
||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_disable(text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_enable( text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_kill(text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_pause(text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_reconnect(text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_reload() FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_resume(text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_set(text, text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_shutdown() FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_suspend() FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_wait_close(text) FROM PUBLIC; | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,121 @@ | ||
-- Add command functions to allow running pgBouncer commands on the target server. Note that the role defined in the user mapping must be given admin access to the pgBouncer admin console. | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_disable(p_dbname text) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
PERFORM dblink_exec('pgbouncer', format('DISABLE %I', p_dbname)); | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_enable(p_dbname text) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
PERFORM dblink_exec('pgbouncer', format('ENABLE %I', p_dbname)); | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_kill(p_dbname text DEFAULT NULL) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
IF p_dbname IS NULL THEN | ||
PERFORM dblink_exec('pgbouncer', 'KILL'); | ||
ELSE | ||
PERFORM dblink_exec('pgbouncer', format('KILL %I', p_dbname)); | ||
END IF; | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_pause(p_dbname text DEFAULT NULL) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
IF p_dbname IS NULL THEN | ||
PERFORM dblink_exec('pgbouncer', 'PAUSE'); | ||
ELSE | ||
PERFORM dblink_exec('pgbouncer', format('PAUSE %I', p_dbname)); | ||
END IF; | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_reconnect(p_dbname text DEFAULT NULL) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
IF p_dbname IS NULL THEN | ||
PERFORM dblink_exec('pgbouncer', 'RECONNECT'); | ||
ELSE | ||
PERFORM dblink_exec('pgbouncer', format('RECONNECT %I', p_dbname)); | ||
END IF; | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_reload() RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
PERFORM dblink_exec('pgbouncer', 'RELOAD'); | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_resume(p_dbname text DEFAULT NULL) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
IF p_dbname IS NULL THEN | ||
PERFORM dblink_exec('pgbouncer', 'RESUME'); | ||
ELSE | ||
PERFORM dblink_exec('pgbouncer', format('RESUME %I', p_dbname)); | ||
END IF; | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_set(p_name text, p_value text) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
PERFORM dblink_exec('pgbouncer', format('SET %s = %L', p_name, p_value)); | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_shutdown() RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
PERFORM dblink_exec('pgbouncer', 'shutdown'); | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_suspend() RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
PERFORM dblink_exec('pgbouncer', 'SUSPEND'); | ||
END | ||
$$; | ||
|
||
CREATE FUNCTION @extschema@.pgbouncer_command_wait_close(p_dbname text DEFAULT NULL) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
IF p_dbname IS NULL THEN | ||
PERFORM dblink_exec('pgbouncer', 'WAIT_CLOSE'); | ||
ELSE | ||
PERFORM dblink_exec('pgbouncer', format('WAIT_CLOSE %I', p_dbname)); | ||
END IF; | ||
END | ||
$$; | ||
|
||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_disable(text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_enable(text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_kill(text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_pause(text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_reconnect(text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_reload() FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_resume(text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_set(text, text) FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_shutdown() FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_suspend() FROM PUBLIC; | ||
REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_wait_close(text) FROM PUBLIC; |