Skip to content

Commit

Permalink
Merge pull request #5 from keithf4/v0.3
Browse files Browse the repository at this point in the history
v0.3 Add support for command functions to control pgBouncer administration
  • Loading branch information
sharmay authored Oct 29, 2020
2 parents e2b760e + 96eafb0 commit dfae75f
Show file tree
Hide file tree
Showing 7 changed files with 284 additions and 5 deletions.
4 changes: 4 additions & 0 deletions CHANGELOG
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.
2 changes: 1 addition & 1 deletion Makefile
Original file line number Diff line number Diff line change
Expand Up @@ -10,7 +10,7 @@ PG94 = $(shell $(PG_CONFIG) --version | egrep " 8\.| 9\.0| 9\.1| 9\.2| 9\.3" > /
ifeq ($(PG94),yes)
all: sql/$(EXTENSION)--$(EXTVERSION).sql

sql/$(EXTENSION)--$(EXTVERSION).sql: sql/*.sql
sql/$(EXTENSION)--$(EXTVERSION).sql: $(sort $(wildcard sql/views/*.sql)) $(sort $(wildcard sql/functions/*.sql))
cat $^ > $@

DATA = $(wildcard updates/*--*.sql) sql/$(EXTENSION)--$(EXTVERSION).sql
Expand Down
35 changes: 33 additions & 2 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -12,8 +12,9 @@ pgbouncer_fdw provides a direct SQL interface to the pgbouncer SHOW commands. It

## Setup

Whichever database role you will be using in the user mapping below will have to be added to the `stats_users` list in the pgbouncer configuration (pgbouncer.ini). You will also need to add this role to the `auth_users` file (see NOTE below). Ensure the role used below is able to connect to the special pgbouncer database and run the SHOW commands before setting up the FDW.
For basic monitoring of statistics, whichever database role you will be using in the user mapping below will have to be added to the `stats_users` list in the pgbouncer configuration (pgbouncer.ini). You will also need to add this role to the `auth_users` file (see NOTE below). Ensure the role used below is able to connect to the special pgbouncer database and run the SHOW commands before setting up the FDW.

For running of the command functions, that role will have to be added to the `admin_users` list in the pgbouncer configuration. It is not recommended that your monitoring role also be given admin console access. It is recommended to have a separate database role for a separate user mapping to allow access to the pgBouncer to run these commands.

If installing from source, run make from the source directory
```
Expand All @@ -36,6 +37,10 @@ CREATE SERVER pgbouncer FOREIGN DATA WRAPPER dblink_fdw OPTIONS (host 'localhost
CREATE USER MAPPING FOR PUBLIC SERVER pgbouncer OPTIONS (user 'ccp_monitoring', password 'mypassword');
```
Optionally create a separate user mapping to allow admin command access. The example below sets the `pg_admin` role that exists in the PostgreSQL databsae to connect to the pgBouncer admin console as the role `pg_admin` which should be in the pgbouncer.ini `admin_users` list
```
CREATE USER MAPPING FOR pgb_admin SERVER pgbouncer OPTIONS (user 'pgb_admin', password 'supersecretpassword');
```
```
CREATE EXTENSION pgbouncer_fdw;
```
Expand All @@ -57,7 +62,33 @@ GRANT SELECT ON pgbouncer_stats TO ccp_monitoring;
GRANT SELECT ON pgbouncer_users TO ccp_monitoring;
```

For added security, execution on the pgBouncer command functions has been revoked from public by default. You will need to explicitly grant execute privileges on the command functions to your pgBouncer admin role if they are being used.
```
GRANT USAGE ON FOREIGN SERVER pgbouncer TO pgb_admin;
GRANT EXECUTE ON FUNCTION pgbouncer_command_disable(text) TO pgb_admin;
GRANT EXECUTE ON FUNCTION pgbouncer_command_enable(text) TO pgb_admin;
GRANT EXECUTE ON FUNCTION pgbouncer_command_kill(text) TO pgb_admin;
GRANT EXECUTE ON FUNCTION pgbouncer_command_pause(text) TO pgb_admin;
GRANT EXECUTE ON FUNCTION pgbouncer_command_reconnect(text) TO pgb_admin;
GRANT EXECUTE ON FUNCTION pgbouncer_command_reload() TO pgb_admin;
GRANT EXECUTE ON FUNCTION pgbouncer_command_resume(text) TO pgb_admin;
GRANT EXECUTE ON FUNCTION pgbouncer_command_set(text, text) TO pgb_admin;
GRANT EXECUTE ON FUNCTION pgbouncer_command_shutdown() TO pgb_admin;
GRANT EXECUTE ON FUNCTION pgbouncer_command_suspend() TO pgb_admin;
GRANT EXECUTE ON FUNCTION pgbouncer_command_wait_close(text) TO pgb_admin;
GRANT SELECT ON pgbouncer_clients TO pgb_admin;
GRANT SELECT ON pgbouncer_config TO pgb_admin;
GRANT SELECT ON pgbouncer_databases TO pgb_admin;
GRANT SELECT ON pgbouncer_dns_hosts TO pgb_admin;
GRANT SELECT ON pgbouncer_dns_zones TO pgb_admin;
GRANT SELECT ON pgbouncer_lists TO pgb_admin;
GRANT SELECT ON pgbouncer_pools TO pgb_admin;
GRANT SELECT ON pgbouncer_servers TO pgb_admin;
GRANT SELECT ON pgbouncer_sockets TO pgb_admin;
GRANT SELECT ON pgbouncer_stats TO pgb_admin;
GRANT SELECT ON pgbouncer_users TO pgb_admin;
```
## Usage
You should be able to query any of the pgbouncer views provided. For the meaning of the views, see the pgbouncer documentation (linked above). Not all views are provided either due to recommendations from author (FDS) or duplication of other view data already provided (STATS_TOTALS, STATS_AVERAGES, etc).

Expand Down
4 changes: 2 additions & 2 deletions pgbouncer_fdw.control
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
121 changes: 121 additions & 0 deletions sql/functions/pgbouncer_fdw_functions.sql
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;

2 changes: 2 additions & 0 deletions sql/pgbouncer_fdw.sql → sql/views/pgbouncer_fdw_views.sql
Original file line number Diff line number Diff line change
@@ -1,3 +1,4 @@

CREATE VIEW @extschema@.pgbouncer_clients AS
SELECT * FROM dblink('pgbouncer', 'show clients') AS x
( type text
Expand Down Expand Up @@ -140,3 +141,4 @@ CREATE VIEW @extschema@.pgbouncer_users AS
SELECT * FROM dblink('pgbouncer', 'show users') AS x
( name text
, pool_mode text);

121 changes: 121 additions & 0 deletions updates/pgbouncer_fdw--0.2--0.3.sql
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;

0 comments on commit dfae75f

Please sign in to comment.