├── .gitignore ├── pgbouncer_fdw.control ├── sql ├── tables │ └── pgbouncer_fdw_tables.sql └── views │ └── pgbouncer_fdw_views.sql ├── Makefile ├── LICENSE.txt ├── updates ├── pgbouncer_fdw--1.0.0--1.0.1.sql ├── pgbouncer_fdw--0.2--0.3.sql ├── pgbouncer_fdw--0.1--0.2.sql ├── pgbouncer_fdw--0.4--0.5.sql ├── pgbouncer_fdw--0.3--0.4.sql ├── pgbouncer_fdw--1.3.0--1.4.0.sql ├── pgbouncer_fdw--1.0.1--1.1.0.sql ├── pgbouncer_fdw--1.1.0--1.2.0.sql └── pgbouncer_fdw--0.5--1.0.0.sql ├── CHANGELOG └── README.md /.gitignore: -------------------------------------------------------------------------------- 1 | *.swp 2 | *.swo 3 | sql/*.sql 4 | -------------------------------------------------------------------------------- /pgbouncer_fdw.control: -------------------------------------------------------------------------------- 1 | default_version = '1.4.0' 2 | comment = 'Extension for querying PgBouncer stats from normal SQL views & running pgbouncer commands from normal SQL functions' 3 | requires = dblink 4 | relocatable = false 5 | -------------------------------------------------------------------------------- /sql/tables/pgbouncer_fdw_tables.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * pgbouncer_fdw_targets 3 | */ 4 | CREATE TABLE @extschema@.pgbouncer_fdw_targets ( 5 | target_host text NOT NULL 6 | , active boolean NOT NULL DEFAULT true 7 | , CONSTRAINT pgbouncer_fdw_targets_pk PRIMARY KEY (target_host) ); 8 | CREATE INDEX pgbouncer_fdw_targets_active_idx ON pgbouncer_fdw_targets (active); 9 | SELECT pg_catalog.pg_extension_config_dump('pgbouncer_fdw_targets', ''); 10 | 11 | INSERT INTO @extschema@.pgbouncer_fdw_targets ( target_host ) VALUES ('pgbouncer'); 12 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = pgbouncer_fdw 2 | EXTVERSION = $(shell grep default_version $(EXTENSION).control | \ 3 | sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/") 4 | 5 | DATA = $(filter-out $(wildcard sql/*--*.sql),$(wildcard sql/*.sql)) 6 | #DOCS = $(wildcard doc/*.md) 7 | PG_CONFIG = pg_config 8 | 9 | all: sql/$(EXTENSION)--$(EXTVERSION).sql 10 | 11 | sql/$(EXTENSION)--$(EXTVERSION).sql: $(sort $(wildcard sql/tables/*.sql)) $(sort $(wildcard sql/functions/*.sql)) $(sort $(wildcard sql/views/*.sql)) 12 | cat $^ > $@ 13 | 14 | DATA = $(wildcard updates/*--*.sql) sql/$(EXTENSION)--$(EXTVERSION).sql 15 | EXTRA_CLEAN = sql/$(EXTENSION)--$(EXTVERSION).sql 16 | 17 | PGXS := $(shell $(PG_CONFIG) --pgxs) 18 | include $(PGXS) 19 | -------------------------------------------------------------------------------- /LICENSE.txt: -------------------------------------------------------------------------------- 1 | LICENSE AND COPYRIGHT 2 | --------------------- 3 | 4 | pgbouncer_fdw is released under the PostgreSQL License, a liberal Open Source license, similar to the BSD or MIT licenses. 5 | 6 | Copyright © 2021-2025 Crunchy Data Solutions, Inc. All Rights Reserved. 7 | 8 | Permission to use, copy, modify, and distribute this software and its documentation for any purpose, without fee, and without a written agreement is hereby granted, provided that the above copyright notice and this paragraph and the following two paragraphs appear in all copies. 9 | 10 | IN NO EVENT SHALL THE AUTHOR BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF THE AUTHOR HAS BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 11 | 12 | THE AUTHOR SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, AND THE AUTHOR HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS. 13 | -------------------------------------------------------------------------------- /updates/pgbouncer_fdw--1.0.0--1.0.1.sql: -------------------------------------------------------------------------------- 1 | -- Fix missing comma that caused missing column "pgbouncer_target_host" in "pgbouncer_servers" and "pgbouncer_dns_zones" views 2 | 3 | CREATE TEMP TABLE pgbouncer_fdw_preserve_privs_temp (statement text); 4 | 5 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 6 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_servers TO '||grantee::text||';' 7 | FROM information_schema.table_privileges 8 | WHERE table_schema = '@extschema@' 9 | AND table_name = 'pgbouncer_servers' 10 | GROUP BY grantee; 11 | 12 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 13 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_dns_zones TO '||grantee::text||';' 14 | FROM information_schema.table_privileges 15 | WHERE table_schema = '@extschema@' 16 | AND table_name = 'pgbouncer_dns_zones' 17 | GROUP BY grantee; 18 | 19 | DROP VIEW @extschema@.pgbouncer_servers; 20 | DROP VIEW @extschema@.pgbouncer_dns_zones; 21 | 22 | CREATE OR REPLACE VIEW @extschema@.pgbouncer_servers AS 23 | SELECT pgbouncer_target_host 24 | , "type" 25 | , "user" 26 | , database 27 | , state 28 | , addr 29 | , port 30 | , local_addr 31 | , local_port 32 | , connect_time 33 | , request_time 34 | , wait 35 | , wait_us 36 | , close_needed 37 | , ptr 38 | , link 39 | , remote_pid 40 | , tls 41 | , application_name 42 | FROM @extschema@.pgbouncer_servers_func(); 43 | 44 | 45 | CREATE VIEW @extschema@.pgbouncer_dns_zones AS 46 | SELECT pgbouncer_target_host 47 | , zonename 48 | , serial 49 | , count 50 | FROM @extschema@.pgbouncer_dns_zones_func(); 51 | 52 | -- Restore dropped object privileges 53 | DO $$ 54 | DECLARE 55 | v_row record; 56 | BEGIN 57 | FOR v_row IN SELECT statement FROM pgbouncer_fdw_preserve_privs_temp LOOP 58 | IF v_row.statement IS NOT NULL THEN 59 | EXECUTE v_row.statement; 60 | END IF; 61 | END LOOP; 62 | END 63 | $$; 64 | 65 | DROP TABLE IF EXISTS pgbouncer_fdw_preserve_privs_temp; 66 | -------------------------------------------------------------------------------- /CHANGELOG: -------------------------------------------------------------------------------- 1 | v1.4.0 2 | -- Update to support column change in databases from reserve_pool to reserve_pool_size in pgBouncer 1.24 3 | -- Set proper data type for pool_size and reserve_pool_size in users 4 | 5 | 6 | v1.3.0 7 | -- Update to support pgBouncer 1.24 8 | -- Improved support for newer columns that don't exist in older versions of pgBouncer 9 | -- Add checks to ensure future compatibility works for all versions of 1.x but stops before 2.x 10 | 11 | 12 | v1.2.0 13 | -- Add support for PgBouncer 1.23. 14 | -- Adds replication column to clients, servers and sockets functions and views. 15 | -- Adds server_lifetime column to databases functions and views. 16 | -- Adds total_server_assignment_count and avg_server_assignment_count columns to stats functions and views. 17 | -- Adds pool_size, max_user_connections and current_connections columns to users functions and views. 18 | 19 | 20 | v1.1.0 21 | -- Add support for PgBouncer 1.21. Adds prepared_statements column to clients, servers and sockets functions and views. 22 | 23 | 24 | v1.0.1 25 | -- Fix missing comma that caused missing column "pgbouncer_target_host" in "pgbouncer_servers" and "pgbouncer_dns_zones" views 26 | 27 | 28 | v1.0.0 29 | -- IMPORTANT NOTE: All objects in this extension are dropped and recreated as part of this update. Privileges ARE NOT preserved as part of this update, so please ensure privileges you have on these objects are preserved before upgrading so that they can be reapplied. Note that execution by PUBLIC on the admin functions is once again revoked by this update. 30 | 31 | -- Add support for gathering statistics from multiple pgBouncer targets 32 | -- A new configuration table has been added to define the names of all FDW servers. 33 | -- All views have an additional column to identify the pgBouncer target 34 | -- All administrative command functions have had a parameter for the FDW server name added to them. These functions intentionally do not use the configuration table to avoid accidentally running an admin command on multiple servers. 35 | 36 | -- Add better support for multiple versions of PgBouncer. Support for 1.17 has been backported into this version of pgbouncer_fdw. 37 | 38 | 39 | v0.5 40 | -- Update to support pgBouncer 1.18.0. Note that as of v0.5, this extension requires at least version 1.18.0 of pgBouncer. If you still need to support an older version, v0.4 works with pgBouncer 1.16 and v0.3 works with older versions of pgBouncer. There are no other changes in this version other than a compatibility update. 41 | -- Several views are dropped and recreated as part of this update. Privileges should be preserved, but it is recommended to double-check them. 42 | 43 | 44 | v0.4 45 | -- Updated to support pgBouncer 1.16.0. Note that as of v0.4, this extension requires at least version 1.16.0 of pgBouncer. If you still need to support an older version, v0.3 still works and there are no other changes in this version other than a compatibility update. 46 | -- All views are dropped and recreated as part of this update. Privileges should be preserved, but it is recommended to double-check them. 47 | 48 | 49 | v0.3 50 | -- 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. 51 | 52 | 53 | v0.2 54 | -- 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. 55 | -------------------------------------------------------------------------------- /updates/pgbouncer_fdw--0.2--0.3.sql: -------------------------------------------------------------------------------- 1 | -- 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. 2 | 3 | CREATE FUNCTION @extschema@.pgbouncer_command_disable(p_dbname text) RETURNS void 4 | LANGUAGE plpgsql 5 | AS $$ 6 | BEGIN 7 | PERFORM dblink_exec('pgbouncer', format('DISABLE %I', p_dbname)); 8 | END 9 | $$; 10 | 11 | CREATE FUNCTION @extschema@.pgbouncer_command_enable(p_dbname text) RETURNS void 12 | LANGUAGE plpgsql 13 | AS $$ 14 | BEGIN 15 | PERFORM dblink_exec('pgbouncer', format('ENABLE %I', p_dbname)); 16 | END 17 | $$; 18 | 19 | CREATE FUNCTION @extschema@.pgbouncer_command_kill(p_dbname text DEFAULT NULL) RETURNS void 20 | LANGUAGE plpgsql 21 | AS $$ 22 | BEGIN 23 | IF p_dbname IS NULL THEN 24 | PERFORM dblink_exec('pgbouncer', 'KILL'); 25 | ELSE 26 | PERFORM dblink_exec('pgbouncer', format('KILL %I', p_dbname)); 27 | END IF; 28 | END 29 | $$; 30 | 31 | CREATE FUNCTION @extschema@.pgbouncer_command_pause(p_dbname text DEFAULT NULL) RETURNS void 32 | LANGUAGE plpgsql 33 | AS $$ 34 | BEGIN 35 | IF p_dbname IS NULL THEN 36 | PERFORM dblink_exec('pgbouncer', 'PAUSE'); 37 | ELSE 38 | PERFORM dblink_exec('pgbouncer', format('PAUSE %I', p_dbname)); 39 | END IF; 40 | END 41 | $$; 42 | 43 | CREATE FUNCTION @extschema@.pgbouncer_command_reconnect(p_dbname text DEFAULT NULL) RETURNS void 44 | LANGUAGE plpgsql 45 | AS $$ 46 | BEGIN 47 | IF p_dbname IS NULL THEN 48 | PERFORM dblink_exec('pgbouncer', 'RECONNECT'); 49 | ELSE 50 | PERFORM dblink_exec('pgbouncer', format('RECONNECT %I', p_dbname)); 51 | END IF; 52 | END 53 | $$; 54 | 55 | CREATE FUNCTION @extschema@.pgbouncer_command_reload() RETURNS void 56 | LANGUAGE plpgsql 57 | AS $$ 58 | BEGIN 59 | PERFORM dblink_exec('pgbouncer', 'RELOAD'); 60 | END 61 | $$; 62 | 63 | CREATE FUNCTION @extschema@.pgbouncer_command_resume(p_dbname text DEFAULT NULL) RETURNS void 64 | LANGUAGE plpgsql 65 | AS $$ 66 | BEGIN 67 | IF p_dbname IS NULL THEN 68 | PERFORM dblink_exec('pgbouncer', 'RESUME'); 69 | ELSE 70 | PERFORM dblink_exec('pgbouncer', format('RESUME %I', p_dbname)); 71 | END IF; 72 | END 73 | $$; 74 | 75 | CREATE FUNCTION @extschema@.pgbouncer_command_set(p_name text, p_value text) RETURNS void 76 | LANGUAGE plpgsql 77 | AS $$ 78 | BEGIN 79 | PERFORM dblink_exec('pgbouncer', format('SET %s = %L', p_name, p_value)); 80 | END 81 | $$; 82 | 83 | CREATE FUNCTION @extschema@.pgbouncer_command_shutdown() RETURNS void 84 | LANGUAGE plpgsql 85 | AS $$ 86 | BEGIN 87 | PERFORM dblink_exec('pgbouncer', 'shutdown'); 88 | END 89 | $$; 90 | 91 | CREATE FUNCTION @extschema@.pgbouncer_command_suspend() RETURNS void 92 | LANGUAGE plpgsql 93 | AS $$ 94 | BEGIN 95 | PERFORM dblink_exec('pgbouncer', 'SUSPEND'); 96 | END 97 | $$; 98 | 99 | CREATE FUNCTION @extschema@.pgbouncer_command_wait_close(p_dbname text DEFAULT NULL) RETURNS void 100 | LANGUAGE plpgsql 101 | AS $$ 102 | BEGIN 103 | IF p_dbname IS NULL THEN 104 | PERFORM dblink_exec('pgbouncer', 'WAIT_CLOSE'); 105 | ELSE 106 | PERFORM dblink_exec('pgbouncer', format('WAIT_CLOSE %I', p_dbname)); 107 | END IF; 108 | END 109 | $$; 110 | 111 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_disable(text) FROM PUBLIC; 112 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_enable(text) FROM PUBLIC; 113 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_kill(text) FROM PUBLIC; 114 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_pause(text) FROM PUBLIC; 115 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_reconnect(text) FROM PUBLIC; 116 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_reload() FROM PUBLIC; 117 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_resume(text) FROM PUBLIC; 118 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_set(text, text) FROM PUBLIC; 119 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_shutdown() FROM PUBLIC; 120 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_suspend() FROM PUBLIC; 121 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_wait_close(text) FROM PUBLIC; 122 | -------------------------------------------------------------------------------- /updates/pgbouncer_fdw--0.1--0.2.sql: -------------------------------------------------------------------------------- 1 | -- Rename objects to have a prefix so installing to public schema is less likely to have naming collisions 2 | 3 | DROP VIEW IF EXISTS @extschema@.clients; 4 | DROP VIEW IF EXISTS @extschema@.config; 5 | DROP VIEW IF EXISTS @extschema@.databases; 6 | DROP VIEW IF EXISTS @extschema@.dns_hosts; 7 | DROP VIEW IF EXISTS @extschema@.dns_zones; 8 | DROP VIEW IF EXISTS @extschema@.lists; 9 | DROP VIEW IF EXISTS @extschema@.pools; 10 | DROP VIEW IF EXISTS @extschema@.servers; 11 | DROP VIEW IF EXISTS @extschema@.sockets; 12 | DROP VIEW IF EXISTS @extschema@.stats; 13 | DROP VIEW IF EXISTS @extschema@.users; 14 | 15 | CREATE VIEW @extschema@.pgbouncer_clients AS 16 | SELECT * FROM dblink('pgbouncer', 'show clients') AS x 17 | ( type text 18 | , "user" text 19 | , database text 20 | , state text 21 | , addr text 22 | , port int 23 | , local_addr text 24 | , local_port int 25 | , connect_time timestamp with time zone 26 | , request_time timestamp with time zone 27 | , wait int 28 | , wait_us int 29 | , close_needed int 30 | , ptr text 31 | , link text 32 | , remote_pid int 33 | , tls text); 34 | 35 | CREATE VIEW @extschema@.pgbouncer_config AS 36 | SELECT * FROM dblink('pgbouncer', 'show config') AS x 37 | ( key text 38 | , value text 39 | , changeable boolean); 40 | 41 | CREATE VIEW @extschema@.pgbouncer_databases AS 42 | SELECT * FROM dblink('pgbouncer', 'show databases') AS x 43 | ( name text 44 | , host text 45 | , port int 46 | , database text 47 | , force_user text 48 | , pool_size int 49 | , reserve_pool int 50 | , pool_mode text 51 | , max_connections int 52 | , current_connections int 53 | , paused int 54 | , disabled int); 55 | 56 | CREATE VIEW @extschema@.pgbouncer_dns_hosts AS 57 | SELECT * FROM dblink('pgbouncer', 'show dns_hosts') AS x 58 | ( hostname text 59 | , ttl bigint 60 | , addrs text); 61 | 62 | CREATE VIEW @extschema@.pgbouncer_dns_zones AS 63 | SELECT * FROM dblink('pgbouncer', 'show dns_zones') AS x 64 | ( zonename text 65 | , serial text 66 | , count int); 67 | 68 | CREATE VIEW @extschema@.pgbouncer_lists AS 69 | SELECT * FROM dblink('pgbouncer', 'show lists') AS x 70 | ( list text 71 | , items int); 72 | 73 | CREATE VIEW @extschema@.pgbouncer_pools AS 74 | SELECT * FROM dblink('pgbouncer', 'show pools') AS x 75 | ( database text 76 | , "user" text 77 | , cl_active int 78 | , cl_waiting int 79 | , sv_active int 80 | , sv_idle int 81 | , sv_used int 82 | , sv_tested int 83 | , sv_login int 84 | , maxwait int 85 | , maxwait_us int 86 | , pool_mode text); 87 | 88 | CREATE VIEW @extschema@.pgbouncer_servers AS 89 | SELECT * FROM dblink('pgbouncer', 'show servers') AS x 90 | ( type text 91 | , "user" text 92 | , database text 93 | , state text 94 | , addr text 95 | , port int 96 | , local_addr text 97 | , local_port int 98 | , connect_time timestamp with time zone 99 | , request_time timestamp with time zone 100 | , wait int 101 | , wait_us int 102 | , close_needed int 103 | , ptr text 104 | , link text 105 | , remote_pid int 106 | , tls text); 107 | 108 | CREATE VIEW @extschema@.pgbouncer_sockets AS 109 | SELECT * FROM dblink('pgbouncer', 'show sockets') AS x 110 | ( type text 111 | , "user" text 112 | , database text 113 | , state text 114 | , addr text 115 | , port int 116 | , local_addr text 117 | , local_port int 118 | , connect_time timestamp with time zone 119 | , request_time timestamp with time zone 120 | , wait int 121 | , wait_us int 122 | , close_needed int 123 | , ptr text 124 | , link text 125 | , remote_pid int 126 | , tls text 127 | , recv_pos int 128 | , pkt_pos int 129 | , pkt_remain int 130 | , send_pos int 131 | , send_remain int 132 | , pkt_avail int 133 | , send_avail int); 134 | 135 | CREATE VIEW @extschema@.pgbouncer_stats AS 136 | SELECT * FROM dblink('pgbouncer', 'show stats') AS x 137 | ( database text 138 | , total_xact_count bigint 139 | , total_query_count bigint 140 | , total_received bigint 141 | , total_sent bigint 142 | , total_xact_time bigint 143 | , total_query_time bigint 144 | , total_wait_time bigint 145 | , avg_xact_count bigint 146 | , avg_query_count bigint 147 | , avg_recv bigint 148 | , avg_sent bigint 149 | , avg_xact_time bigint 150 | , avg_query_time bigint 151 | , avg_wait_time bigint ); 152 | 153 | CREATE VIEW @extschema@.pgbouncer_users AS 154 | SELECT * FROM dblink('pgbouncer', 'show users') AS x 155 | ( name text 156 | , pool_mode text); 157 | -------------------------------------------------------------------------------- /sql/views/pgbouncer_fdw_views.sql: -------------------------------------------------------------------------------- 1 | CREATE VIEW @extschema@.pgbouncer_version AS 2 | SELECT pgbouncer_target_host 3 | , version_major 4 | , version_minor 5 | , version_patch 6 | FROM @extschema@.pgbouncer_version_func(); 7 | 8 | 9 | CREATE VIEW @extschema@.pgbouncer_clients AS 10 | SELECT pgbouncer_target_host 11 | , "type" 12 | , "user" 13 | , database 14 | , replication 15 | , state 16 | , addr 17 | , port 18 | , local_addr 19 | , local_port 20 | , connect_time 21 | , request_time 22 | , wait 23 | , wait_us 24 | , close_needed 25 | , ptr 26 | , link 27 | , remote_pid 28 | , tls 29 | , application_name 30 | , prepared_statements 31 | , id 32 | FROM @extschema@.pgbouncer_clients_func(); 33 | 34 | 35 | CREATE VIEW @extschema@.pgbouncer_config AS 36 | SELECT pgbouncer_target_host 37 | , key 38 | , value 39 | , "default" 40 | , changeable 41 | FROM @extschema@.pgbouncer_config_func(); 42 | 43 | CREATE VIEW @extschema@.pgbouncer_databases AS 44 | SELECT pgbouncer_target_host 45 | , name 46 | , host 47 | , port 48 | , database 49 | , force_user 50 | , pool_size 51 | , min_pool_size 52 | , reserve_pool_size 53 | , server_lifetime 54 | , pool_mode 55 | , load_balance_hosts 56 | , max_connections 57 | , current_connections 58 | , max_client_connections 59 | , current_client_connections 60 | , paused 61 | , disabled 62 | FROM @extschema@.pgbouncer_databases_func(); 63 | 64 | CREATE VIEW @extschema@.pgbouncer_dns_hosts AS 65 | SELECT pgbouncer_target_host 66 | , hostname 67 | , ttl 68 | , addrs 69 | FROM @extschema@.pgbouncer_dns_hosts_func(); 70 | 71 | 72 | CREATE VIEW @extschema@.pgbouncer_dns_zones AS 73 | SELECT pgbouncer_target_host 74 | , zonename 75 | , serial 76 | , count 77 | FROM @extschema@.pgbouncer_dns_zones_func(); 78 | 79 | 80 | CREATE VIEW @extschema@.pgbouncer_lists AS 81 | SELECT pgbouncer_target_host 82 | , list 83 | , items 84 | FROM @extschema@.pgbouncer_lists_func(); 85 | 86 | 87 | CREATE VIEW @extschema@.pgbouncer_pools AS 88 | SELECT pgbouncer_target_host 89 | , database 90 | , "user" 91 | , cl_active 92 | , cl_waiting 93 | , cl_active_cancel_req 94 | , cl_waiting_cancel_req 95 | , sv_active 96 | , sv_active_cancel 97 | , sv_being_canceled 98 | , sv_idle 99 | , sv_used 100 | , sv_tested 101 | , sv_login 102 | , maxwait 103 | , maxwait_us 104 | , pool_mode 105 | , load_balance_hosts 106 | FROM @extschema@.pgbouncer_pools_func(); 107 | 108 | 109 | CREATE VIEW @extschema@.pgbouncer_servers AS 110 | SELECT pgbouncer_target_host 111 | , "type" 112 | , "user" 113 | , database 114 | , replication 115 | , state 116 | , addr 117 | , port 118 | , local_addr 119 | , local_port 120 | , connect_time 121 | , request_time 122 | , wait 123 | , wait_us 124 | , close_needed 125 | , ptr 126 | , link 127 | , remote_pid 128 | , tls 129 | , application_name 130 | , prepared_statements 131 | , id 132 | FROM @extschema@.pgbouncer_servers_func(); 133 | 134 | 135 | CREATE VIEW @extschema@.pgbouncer_sockets AS 136 | SELECT pgbouncer_target_host 137 | , "type" 138 | , "user" 139 | , database 140 | , replication 141 | , state 142 | , addr 143 | , port 144 | , local_addr 145 | , local_port 146 | , connect_time 147 | , request_time 148 | , wait 149 | , wait_us 150 | , close_needed 151 | , ptr 152 | , link 153 | , remote_pid 154 | , tls 155 | , application_name 156 | , recv_pos 157 | , pkt_pos 158 | , pkt_remain 159 | , send_pos 160 | , send_remain 161 | , pkt_avail 162 | , send_avail 163 | , prepared_statements 164 | , id 165 | FROM @extschema@.pgbouncer_sockets_func(); 166 | 167 | 168 | CREATE VIEW @extschema@.pgbouncer_stats AS 169 | SELECT pgbouncer_target_host 170 | , database 171 | , total_server_assignment_count 172 | , total_xact_count 173 | , total_query_count 174 | , total_received 175 | , total_sent 176 | , total_xact_time 177 | , total_query_time 178 | , total_wait_time 179 | , avg_server_assignment_count 180 | , avg_xact_count 181 | , avg_query_count 182 | , avg_recv 183 | , avg_sent 184 | , avg_xact_time 185 | , avg_query_time 186 | , avg_wait_time 187 | , avg_client_parse_count 188 | , avg_server_parse_count 189 | , avg_bind_count 190 | FROM @extschema@.pgbouncer_stats_func(); 191 | 192 | 193 | CREATE VIEW @extschema@.pgbouncer_users AS 194 | SELECT pgbouncer_target_host 195 | , name 196 | , pool_size 197 | , reserve_pool_size 198 | , pool_mode 199 | , max_user_connections 200 | , current_connections 201 | , max_user_client_connections 202 | , current_client_connections 203 | FROM @extschema@.pgbouncer_users_func(); 204 | -------------------------------------------------------------------------------- /updates/pgbouncer_fdw--0.4--0.5.sql: -------------------------------------------------------------------------------- 1 | CREATE TEMP TABLE pgbouncer_fdw_preserve_privs_temp (statement text); 2 | 3 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 4 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_clients TO '||grantee::text||';' 5 | FROM information_schema.table_privileges 6 | WHERE table_schema = '@extschema@' 7 | AND table_name = 'pgbouncer_clients' 8 | GROUP BY grantee; 9 | 10 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 11 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_pools TO '||grantee::text||';' 12 | FROM information_schema.table_privileges 13 | WHERE table_schema = '@extschema@' 14 | AND table_name = 'pgbouncer_pools' 15 | GROUP BY grantee; 16 | 17 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 18 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_servers TO '||grantee::text||';' 19 | FROM information_schema.table_privileges 20 | WHERE table_schema = '@extschema@' 21 | AND table_name = 'pgbouncer_servers' 22 | GROUP BY grantee; 23 | 24 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 25 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_sockets TO '||grantee::text||';' 26 | FROM information_schema.table_privileges 27 | WHERE table_schema = '@extschema@' 28 | AND table_name = 'pgbouncer_sockets' 29 | GROUP BY grantee; 30 | 31 | DROP VIEW @extschema@.pgbouncer_clients; 32 | DROP VIEW @extschema@.pgbouncer_pools; 33 | DROP VIEW @extschema@.pgbouncer_servers; 34 | DROP VIEW @extschema@.pgbouncer_sockets; 35 | 36 | CREATE VIEW @extschema@.pgbouncer_clients AS 37 | SELECT type 38 | , "user" 39 | , database 40 | , state 41 | , addr 42 | , port 43 | , local_addr 44 | , local_port 45 | , connect_time 46 | , request_time 47 | , wait 48 | , wait_us 49 | , close_needed 50 | , ptr 51 | , link 52 | , remote_pid 53 | , tls 54 | , application_name 55 | FROM dblink('pgbouncer', 'show clients') AS x 56 | ( type text 57 | , "user" text 58 | , database text 59 | , state text 60 | , addr text 61 | , port int 62 | , local_addr text 63 | , local_port int 64 | , connect_time timestamp with time zone 65 | , request_time timestamp with time zone 66 | , wait int 67 | , wait_us int 68 | , close_needed int 69 | , ptr text 70 | , link text 71 | , remote_pid int 72 | , tls text 73 | , application_name text 74 | ); 75 | 76 | CREATE VIEW @extschema@.pgbouncer_pools AS 77 | SELECT database 78 | , "user" 79 | , cl_active 80 | , cl_waiting 81 | , cl_active_cancel_req 82 | , cl_waiting_cancel_req 83 | , sv_active 84 | , sv_active_cancel 85 | , sv_being_canceled 86 | , sv_idle 87 | , sv_used 88 | , sv_tested 89 | , sv_login 90 | , maxwait 91 | , maxwait_us 92 | , pool_mode 93 | FROM dblink('pgbouncer', 'show pools') AS x 94 | ( database text 95 | , "user" text 96 | , cl_active int 97 | , cl_waiting int 98 | , cl_active_cancel_req int 99 | , cl_waiting_cancel_req int 100 | , sv_active int 101 | , sv_active_cancel int 102 | , sv_being_canceled int 103 | , sv_idle int 104 | , sv_used int 105 | , sv_tested int 106 | , sv_login int 107 | , maxwait int 108 | , maxwait_us int 109 | , pool_mode text 110 | ); 111 | 112 | CREATE VIEW @extschema@.pgbouncer_servers AS 113 | SELECT type 114 | , "user" 115 | , database 116 | , state 117 | , addr 118 | , port 119 | , local_addr 120 | , local_port 121 | , connect_time 122 | , request_time 123 | , wait 124 | , wait_us 125 | , close_needed 126 | , ptr 127 | , link 128 | , remote_pid 129 | , tls 130 | , application_name 131 | FROM dblink('pgbouncer', 'show servers') AS x 132 | ( type text 133 | , "user" text 134 | , database text 135 | , state text 136 | , addr text 137 | , port int 138 | , local_addr text 139 | , local_port int 140 | , connect_time timestamp with time zone 141 | , request_time timestamp with time zone 142 | , wait int 143 | , wait_us int 144 | , close_needed int 145 | , ptr text 146 | , link text 147 | , remote_pid int 148 | , tls text 149 | , application_name text 150 | ); 151 | 152 | 153 | CREATE VIEW @extschema@.pgbouncer_sockets AS 154 | SELECT type 155 | , "user" 156 | , database 157 | , state 158 | , addr 159 | , port 160 | , local_addr 161 | , local_port 162 | , connect_time 163 | , request_time 164 | , wait 165 | , wait_us 166 | , close_needed 167 | , ptr 168 | , link 169 | , remote_pid 170 | , tls 171 | , application_name 172 | , recv_pos 173 | , pkt_pos 174 | , pkt_remain 175 | , send_pos 176 | , send_remain 177 | , pkt_avail 178 | , send_avail 179 | FROM dblink('pgbouncer', 'show sockets') AS x 180 | ( type text 181 | , "user" text 182 | , database text 183 | , state text 184 | , addr text 185 | , port int 186 | , local_addr text 187 | , local_port int 188 | , connect_time timestamp with time zone 189 | , request_time timestamp with time zone 190 | , wait int 191 | , wait_us int 192 | , close_needed int 193 | , ptr text 194 | , link text 195 | , remote_pid int 196 | , tls text 197 | , application_name text 198 | , recv_pos int 199 | , pkt_pos int 200 | , pkt_remain int 201 | , send_pos int 202 | , send_remain int 203 | , pkt_avail int 204 | , send_avail int 205 | ); 206 | 207 | -- Restore dropped object privileges 208 | DO $$ 209 | DECLARE 210 | v_row record; 211 | BEGIN 212 | FOR v_row IN SELECT statement FROM pgbouncer_fdw_preserve_privs_temp LOOP 213 | IF v_row.statement IS NOT NULL THEN 214 | EXECUTE v_row.statement; 215 | END IF; 216 | END LOOP; 217 | END 218 | $$; 219 | 220 | DROP TABLE IF EXISTS pgbouncer_fdw_preserve_privs_temp; 221 | -------------------------------------------------------------------------------- /updates/pgbouncer_fdw--0.3--0.4.sql: -------------------------------------------------------------------------------- 1 | CREATE TEMP TABLE pgbouncer_fdw_preserve_privs_temp (statement text); 2 | 3 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 4 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_clients TO '||grantee::text||';' 5 | FROM information_schema.table_privileges 6 | WHERE table_schema = '@extschema@' 7 | AND table_name = 'pgbouncer_clients' 8 | GROUP BY grantee; 9 | 10 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 11 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_config TO '||grantee::text||';' 12 | FROM information_schema.table_privileges 13 | WHERE table_schema = '@extschema@' 14 | AND table_name = 'pgbouncer_config' 15 | GROUP BY grantee; 16 | 17 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 18 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_databases TO '||grantee::text||';' 19 | FROM information_schema.table_privileges 20 | WHERE table_schema = '@extschema@' 21 | AND table_name = 'pgbouncer_databases' 22 | GROUP BY grantee; 23 | 24 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 25 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_dns_hosts TO '||grantee::text||';' 26 | FROM information_schema.table_privileges 27 | WHERE table_schema = '@extschema@' 28 | AND table_name = 'pgbouncer_dns_hosts' 29 | GROUP BY grantee; 30 | 31 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 32 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_dns_zones TO '||grantee::text||';' 33 | FROM information_schema.table_privileges 34 | WHERE table_schema = '@extschema@' 35 | AND table_name = 'pgbouncer_dns_zones' 36 | GROUP BY grantee; 37 | 38 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 39 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_lists TO '||grantee::text||';' 40 | FROM information_schema.table_privileges 41 | WHERE table_schema = '@extschema@' 42 | AND table_name = 'pgbouncer_lists' 43 | GROUP BY grantee; 44 | 45 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 46 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_pools TO '||grantee::text||';' 47 | FROM information_schema.table_privileges 48 | WHERE table_schema = '@extschema@' 49 | AND table_name = 'pgbouncer_pools' 50 | GROUP BY grantee; 51 | 52 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 53 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_servers TO '||grantee::text||';' 54 | FROM information_schema.table_privileges 55 | WHERE table_schema = '@extschema@' 56 | AND table_name = 'pgbouncer_servers' 57 | GROUP BY grantee; 58 | 59 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 60 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_sockets TO '||grantee::text||';' 61 | FROM information_schema.table_privileges 62 | WHERE table_schema = '@extschema@' 63 | AND table_name = 'pgbouncer_sockets' 64 | GROUP BY grantee; 65 | 66 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 67 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_stats TO '||grantee::text||';' 68 | FROM information_schema.table_privileges 69 | WHERE table_schema = '@extschema@' 70 | AND table_name = 'pgbouncer_stats' 71 | GROUP BY grantee; 72 | 73 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 74 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_users TO '||grantee::text||';' 75 | FROM information_schema.table_privileges 76 | WHERE table_schema = '@extschema@' 77 | AND table_name = 'pgbouncer_users' 78 | GROUP BY grantee; 79 | 80 | DROP VIEW @extschema@.pgbouncer_clients; 81 | DROP VIEW @extschema@.pgbouncer_config; 82 | DROP VIEW @extschema@.pgbouncer_databases; 83 | DROP VIEW @extschema@.pgbouncer_dns_hosts; 84 | DROP VIEW @extschema@.pgbouncer_dns_zones; 85 | DROP VIEW @extschema@.pgbouncer_lists; 86 | DROP VIEW @extschema@.pgbouncer_pools; 87 | DROP VIEW @extschema@.pgbouncer_servers; 88 | DROP VIEW @extschema@.pgbouncer_sockets; 89 | DROP VIEW @extschema@.pgbouncer_stats; 90 | DROP VIEW @extschema@.pgbouncer_users; 91 | 92 | CREATE VIEW @extschema@.pgbouncer_clients AS 93 | SELECT type 94 | , "user" 95 | , database 96 | , state 97 | , addr 98 | , port 99 | , local_addr 100 | , local_port 101 | , connect_time 102 | , request_time 103 | , wait 104 | , wait_us 105 | , close_needed 106 | , ptr 107 | , link 108 | , remote_pid 109 | , tls 110 | FROM dblink('pgbouncer', 'show clients') AS x 111 | ( type text 112 | , "user" text 113 | , database text 114 | , state text 115 | , addr text 116 | , port int 117 | , local_addr text 118 | , local_port int 119 | , connect_time timestamp with time zone 120 | , request_time timestamp with time zone 121 | , wait int 122 | , wait_us int 123 | , close_needed int 124 | , ptr text 125 | , link text 126 | , remote_pid int 127 | , tls text); 128 | 129 | 130 | CREATE VIEW @extschema@.pgbouncer_config AS 131 | SELECT key 132 | , value 133 | , "default" 134 | , changeable 135 | FROM dblink('pgbouncer', 'show config') AS x 136 | ( key text 137 | , value text 138 | , "default" text 139 | , changeable boolean); 140 | 141 | 142 | CREATE VIEW @extschema@.pgbouncer_databases AS 143 | SELECT name 144 | , host 145 | , port 146 | , database 147 | , force_user 148 | , pool_size 149 | , min_pool_size 150 | , reserve_pool 151 | , pool_mode 152 | , max_connections 153 | , current_connections 154 | , paused 155 | , disabled 156 | FROM dblink('pgbouncer', 'show databases') AS x 157 | ( name text 158 | , host text 159 | , port int 160 | , database text 161 | , force_user text 162 | , pool_size int 163 | , min_pool_size int 164 | , reserve_pool int 165 | , pool_mode text 166 | , max_connections int 167 | , current_connections int 168 | , paused int 169 | , disabled int); 170 | 171 | 172 | CREATE VIEW @extschema@.pgbouncer_dns_hosts AS 173 | SELECT hostname 174 | , ttl 175 | , addrs 176 | FROM dblink('pgbouncer', 'show dns_hosts') AS x 177 | ( hostname text 178 | , ttl bigint 179 | , addrs text); 180 | 181 | 182 | CREATE VIEW @extschema@.pgbouncer_dns_zones AS 183 | SELECT zonename 184 | , serial 185 | , count 186 | FROM dblink('pgbouncer', 'show dns_zones') AS x 187 | ( zonename text 188 | , serial text 189 | , count int); 190 | 191 | 192 | CREATE VIEW @extschema@.pgbouncer_lists AS 193 | SELECT list 194 | , items 195 | FROM dblink('pgbouncer', 'show lists') AS x 196 | ( list text 197 | , items int); 198 | 199 | 200 | CREATE VIEW @extschema@.pgbouncer_pools AS 201 | SELECT database 202 | , "user" 203 | , cl_active 204 | , cl_waiting 205 | , cl_cancel_req 206 | , sv_active 207 | , sv_idle 208 | , sv_used 209 | , sv_tested 210 | , sv_login 211 | , maxwait 212 | , maxwait_us 213 | , pool_mode 214 | FROM dblink('pgbouncer', 'show pools') AS x 215 | ( database text 216 | , "user" text 217 | , cl_active int 218 | , cl_waiting int 219 | , cl_cancel_req int 220 | , sv_active int 221 | , sv_idle int 222 | , sv_used int 223 | , sv_tested int 224 | , sv_login int 225 | , maxwait int 226 | , maxwait_us int 227 | , pool_mode text); 228 | 229 | 230 | CREATE VIEW @extschema@.pgbouncer_servers AS 231 | SELECT type 232 | , "user" 233 | , database 234 | , state 235 | , addr 236 | , port 237 | , local_addr 238 | , local_port 239 | , connect_time 240 | , request_time 241 | , wait 242 | , wait_us 243 | , close_needed 244 | , ptr 245 | , link 246 | , remote_pid 247 | , tls 248 | FROM dblink('pgbouncer', 'show servers') AS x 249 | ( type text 250 | , "user" text 251 | , database text 252 | , state text 253 | , addr text 254 | , port int 255 | , local_addr text 256 | , local_port int 257 | , connect_time timestamp with time zone 258 | , request_time timestamp with time zone 259 | , wait int 260 | , wait_us int 261 | , close_needed int 262 | , ptr text 263 | , link text 264 | , remote_pid int 265 | , tls text); 266 | 267 | 268 | CREATE VIEW @extschema@.pgbouncer_sockets AS 269 | SELECT type 270 | , "user" 271 | , database 272 | , state 273 | , addr 274 | , port 275 | , local_addr 276 | , local_port 277 | , connect_time 278 | , request_time 279 | , wait 280 | , wait_us 281 | , close_needed 282 | , ptr 283 | , link 284 | , remote_pid 285 | , tls 286 | , recv_pos 287 | , pkt_pos 288 | , pkt_remain 289 | , send_pos 290 | , send_remain 291 | , pkt_avail 292 | , send_avail 293 | FROM dblink('pgbouncer', 'show sockets') AS x 294 | ( type text 295 | , "user" text 296 | , database text 297 | , state text 298 | , addr text 299 | , port int 300 | , local_addr text 301 | , local_port int 302 | , connect_time timestamp with time zone 303 | , request_time timestamp with time zone 304 | , wait int 305 | , wait_us int 306 | , close_needed int 307 | , ptr text 308 | , link text 309 | , remote_pid int 310 | , tls text 311 | , recv_pos int 312 | , pkt_pos int 313 | , pkt_remain int 314 | , send_pos int 315 | , send_remain int 316 | , pkt_avail int 317 | , send_avail int); 318 | 319 | 320 | CREATE VIEW @extschema@.pgbouncer_stats AS 321 | SELECT database 322 | , total_xact_count 323 | , total_query_count 324 | , total_received 325 | , total_sent 326 | , total_xact_time 327 | , total_query_time 328 | , total_wait_time 329 | , avg_xact_count 330 | , avg_query_count 331 | , avg_recv 332 | , avg_sent 333 | , avg_xact_time 334 | , avg_query_time 335 | , avg_wait_time 336 | FROM dblink('pgbouncer', 'show stats') AS x 337 | ( database text 338 | , total_xact_count bigint 339 | , total_query_count bigint 340 | , total_received bigint 341 | , total_sent bigint 342 | , total_xact_time bigint 343 | , total_query_time bigint 344 | , total_wait_time bigint 345 | , avg_xact_count bigint 346 | , avg_query_count bigint 347 | , avg_recv bigint 348 | , avg_sent bigint 349 | , avg_xact_time bigint 350 | , avg_query_time bigint 351 | , avg_wait_time bigint ); 352 | 353 | 354 | CREATE VIEW @extschema@.pgbouncer_users AS 355 | SELECT name 356 | , pool_mode 357 | FROM dblink('pgbouncer', 'show users') AS x 358 | ( name text 359 | , pool_mode text); 360 | 361 | 362 | -- Restore dropped object privileges 363 | DO $$ 364 | DECLARE 365 | v_row record; 366 | BEGIN 367 | FOR v_row IN SELECT statement FROM pgbouncer_fdw_preserve_privs_temp LOOP 368 | IF v_row.statement IS NOT NULL THEN 369 | EXECUTE v_row.statement; 370 | END IF; 371 | END LOOP; 372 | END 373 | $$; 374 | 375 | DROP TABLE IF EXISTS pgbouncer_fdw_preserve_privs_temp; 376 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # PgBouncer Foreign Data Wrapper 2 | 3 | ## Introduction 4 | 5 | pgbouncer_fdw provides a direct SQL interface to the PgBouncer SHOW commands. It takes advantage of the dblink_fdw feature to provide a more typical, table-like interface to the current status of your PgBouncer server(s). This makes it easier to set up monitoring or other services that require direct access to PgBouncer statistics. 6 | 7 | ## Requirements 8 | 9 | * PostgreSQL 11+ - https://www.postgresql.org 10 | * dblink (contrib module) - https://www.postgresql.org/docs/current/dblink.html 11 | * PgBouncer 1.17+ - https://pgbouncer.github.io 12 | 13 | ## Installation 14 | 15 | ### Database Users 16 | 17 | For basic monitoring of statistics, whichever database role(s) 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 any of these roles to the PgBouncer `auth_users` file. The auth_query method in PgBouncer cannot be used to connect to the special `pgbouncer` database where the SHOW commands must be run. Ensure the role(s) used are able to connect to the special `pgbouncer` database and run the SHOW commands before setting up the FDW. 18 | 19 | For running of the command functions, roles will have to be added to the `admin_users` list in the PgBouncer configuration. It is not recommended that your monitoring roles 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. 20 | 21 | ### Extension Setup 22 | 23 | 1. If installing from source, run make from the source directory 24 | ``` 25 | make install 26 | ``` 27 | 28 | 2. The dblink extension must be created in a schema that is within the search path of the role that will be used for the user mapping below. A default location of the PUBLIC schema is the easiest. 29 | ``` 30 | CREATE EXTENSION dblink; 31 | ``` 32 | 33 | 3. Create the extension in the monitoring database. PgBouncer statistics are global so it only needs to be monitored from a single database. If you have multiple databases in your cluster, it is recommended to just install it to the default `postgres` database, or whichever one is being used as a global database that will never be dropped. 34 | ``` 35 | CREATE EXTENSION pgbouncer_fdw; 36 | ``` 37 | 38 | 4. Create one or more FDW servers in the same database where the extension was installed. 39 | 40 | a. If only a single PgBouncer server is the target, leave FDW the server name as `pgbouncer` to use the default configuration. This avoids needing to use the configuration table at all. Set the port(s) to whichever one PgBouncer itself is running on, NOT the postgres database. 41 | 42 | ``` 43 | CREATE SERVER pgbouncer FOREIGN DATA WRAPPER dblink_fdw OPTIONS (host 'localhost', 44 | port '6432', 45 | dbname 'pgbouncer'); 46 | ``` 47 | b. If more than one PgBouncer needs to be targeted, give each FDW server a unique name and add those names to the `pgbouncer_fdw_targets` configuration table. 48 | ``` 49 | CREATE SERVER pgbouncer1 FOREIGN DATA WRAPPER dblink_fdw OPTIONS (host '192.168.122.12', 50 | port '6432', 51 | dbname 'pgbouncer'); 52 | 53 | CREATE SERVER pgbouncer2 FOREIGN DATA WRAPPER dblink_fdw OPTIONS (host '192.168.122.13', 54 | port '6432', 55 | dbname 'pgbouncer'); 56 | 57 | INSERT INTO pgbouncer_fdw_targets (target_host) VALUES ('pgbouncer1'),('pgbouncer2'); 58 | ``` 59 | If you do not have an FDW server named `pgbouncer`, be sure to deactivate or remove that default entry in the configuration table. 60 | ``` 61 | UPDATE pgbouncer_fdw_targets SET active = false WHERE target_host = 'pgbouncer'; 62 | ``` 63 | 64 | 5. Create user mapping(s) with your preferred credentials in the same database as the FDW(s). 65 | ``` 66 | CREATE USER MAPPING FOR PUBLIC SERVER pgbouncer OPTIONS (user 'ccp_monitoring', password 'mypassword'); 67 | ``` 68 | If you've configured multiple pgbouncer targets, ensure you've also set the user mappings for all PgBouncer targets. 69 | 70 | Optionally create a separate user mapping to allow admin command access. The example below sets the `pgb_admin` role that exists in the PostgreSQL database to connect to the PgBouncer admin console as the role `pgb_admin` which should be in the pgbouncer.ini `admin_users` list 71 | ``` 72 | CREATE USER MAPPING FOR pgb_admin SERVER pgbouncer OPTIONS (user 'pgb_admin', password 'supersecretpassword'); 73 | ``` 74 | 75 | 6. Grant necessary permissions on extension objects to the user mapping role 76 | ``` 77 | GRANT USAGE ON FOREIGN SERVER pgbouncer TO ccp_monitoring; 78 | 79 | GRANT SELECT ON pgbouncer_clients TO ccp_monitoring; 80 | GRANT SELECT ON pgbouncer_config TO ccp_monitoring; 81 | GRANT SELECT ON pgbouncer_databases TO ccp_monitoring; 82 | GRANT SELECT ON pgbouncer_dns_hosts TO ccp_monitoring; 83 | GRANT SELECT ON pgbouncer_dns_zones TO ccp_monitoring; 84 | GRANT SELECT ON pgbouncer_lists TO ccp_monitoring; 85 | GRANT SELECT ON pgbouncer_pools TO ccp_monitoring; 86 | GRANT SELECT ON pgbouncer_servers TO ccp_monitoring; 87 | GRANT SELECT ON pgbouncer_sockets TO ccp_monitoring; 88 | GRANT SELECT ON pgbouncer_stats TO ccp_monitoring; 89 | GRANT SELECT ON pgbouncer_users TO ccp_monitoring; 90 | 91 | ``` 92 | Please remember that if you are monitoring multiple PgBouncers, you may need to do these grants for additional FDW servers. 93 | 94 | 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. 95 | ``` 96 | GRANT USAGE ON FOREIGN SERVER pgbouncer TO pgb_admin; 97 | 98 | GRANT EXECUTE ON FUNCTION pgbouncer_command_disable(text) TO pgb_admin; 99 | GRANT EXECUTE ON FUNCTION pgbouncer_command_enable(text) TO pgb_admin; 100 | GRANT EXECUTE ON FUNCTION pgbouncer_command_kill(text) TO pgb_admin; 101 | GRANT EXECUTE ON FUNCTION pgbouncer_command_pause(text) TO pgb_admin; 102 | GRANT EXECUTE ON FUNCTION pgbouncer_command_reconnect(text) TO pgb_admin; 103 | GRANT EXECUTE ON FUNCTION pgbouncer_command_reload() TO pgb_admin; 104 | GRANT EXECUTE ON FUNCTION pgbouncer_command_resume(text) TO pgb_admin; 105 | GRANT EXECUTE ON FUNCTION pgbouncer_command_set(text, text) TO pgb_admin; 106 | GRANT EXECUTE ON FUNCTION pgbouncer_command_shutdown() TO pgb_admin; 107 | GRANT EXECUTE ON FUNCTION pgbouncer_command_suspend() TO pgb_admin; 108 | GRANT EXECUTE ON FUNCTION pgbouncer_command_wait_close(text) TO pgb_admin; 109 | GRANT SELECT ON pgbouncer_clients TO pgb_admin; 110 | GRANT SELECT ON pgbouncer_config TO pgb_admin; 111 | GRANT SELECT ON pgbouncer_databases TO pgb_admin; 112 | GRANT SELECT ON pgbouncer_dns_hosts TO pgb_admin; 113 | GRANT SELECT ON pgbouncer_dns_zones TO pgb_admin; 114 | GRANT SELECT ON pgbouncer_lists TO pgb_admin; 115 | GRANT SELECT ON pgbouncer_pools TO pgb_admin; 116 | GRANT SELECT ON pgbouncer_servers TO pgb_admin; 117 | GRANT SELECT ON pgbouncer_sockets TO pgb_admin; 118 | GRANT SELECT ON pgbouncer_stats TO pgb_admin; 119 | GRANT SELECT ON pgbouncer_users TO pgb_admin; 120 | ``` 121 | 122 | ## Usage 123 | 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 due to recommendations from upstream author (FDS) or duplication of data already provided by other views (STATS_TOTALS, STATS_AVERAGES, etc). 124 | 125 | ``` 126 | postgres=# select * from pgbouncer_pools; 127 | -[ RECORD 1 ]---------+----------- 128 | pgbouncer_target_host | pgbouncer 129 | database | pgbouncer 130 | user | pgbouncer 131 | cl_active | 1 132 | cl_waiting | 0 133 | cl_active_cancel_req | 0 134 | cl_waiting_cancel_req | 0 135 | sv_active | 0 136 | sv_active_cancel | 0 137 | sv_being_canceled | 0 138 | sv_idle | 0 139 | sv_used | 0 140 | sv_tested | 0 141 | sv_login | 0 142 | maxwait | 0 143 | maxwait_us | 0 144 | pool_mode | statement 145 | -[ RECORD 2 ]---------+----------- 146 | pgbouncer_target_host | pgbouncer2 147 | database | pgbouncer 148 | user | pgbouncer 149 | cl_active | 1 150 | cl_waiting | 0 151 | cl_active_cancel_req | 0 152 | cl_waiting_cancel_req | 0 153 | sv_active | 0 154 | sv_active_cancel | 0 155 | sv_being_canceled | 0 156 | sv_idle | 0 157 | sv_used | 0 158 | sv_tested | 0 159 | sv_login | 0 160 | maxwait | 0 161 | maxwait_us | 0 162 | pool_mode | statement 163 | ``` 164 | 165 | ## FAQ 166 | 167 | *Q: If connecting to multiple PgBouncer's, how does `pgbouncer_fdw` handle one or more of the target hosts being down while others are up?* 168 | 169 | A: A warning is given for each target host that cannot be connected to. The warning contains the full context of the original error message to help with debugging. 170 | 171 | Hosts that are still up should have their metrics returned. Example with `pgbouncer2` target down. 172 | ``` 173 | postgres=# select * from pgbouncer_fdw_targets ; 174 | target_host | active 175 | -------------+-------- 176 | pgbouncer | t 177 | pgbouncer2 | t 178 | (2 rows) 179 | ``` 180 | ``` 181 | postgres=# select * from pgbouncer_clients; 182 | WARNING: pgbouncer_fdw: Unable to establish connection to PgBouncer target host: pgbouncer2. Continuing to additional hosts. 183 | ORIGINAL ERROR: could not establish connection 184 | CONTEXT: SQL statement "SELECT 185 | v_row.target_host AS pgbouncer_target_host 186 | , split_part(substring(version from '\d.+'), '.', 1)::int AS version_major 187 | , split_part(substring(version from '\d.+'), '.', 2)::int AS version_minor 188 | , split_part(substring(version from '\d.+'), '.', 3)::int AS version_patch 189 | FROM dblink(v_row.target_host, 'show version') AS x 190 | ( 191 | version text 192 | )" 193 | PL/pgSQL function pgbouncer_version_func(text) line 18 at RETURN QUERY 194 | SQL statement "SELECT version_major, version_minor 195 | FROM public.pgbouncer_version_func(v_row.target_host)" 196 | PL/pgSQL function pgbouncer_clients_func() line 16 at SQL statement 197 | DETAIL: connection to server at "192.168.122.12", port 6432 failed: Connection refused 198 | Is the server running on that host and accepting TCP/IP connections? 199 | HINT: 200 | -[ RECORD 1 ]---------+--------------------------- 201 | pgbouncer_target_host | pgbouncer 202 | type | C 203 | user | ccp_monitoring 204 | database | pgbouncer 205 | state | active 206 | addr | 192.168.122.16 207 | port | 56574 208 | local_addr | 192.168.122.13 209 | local_port | 6432 210 | connect_time | 2023-05-12 17:05:52-04 211 | request_time | 2023-05-12 17:05:52-04 212 | wait | 0 213 | wait_us | 0 214 | close_needed | 0 215 | ptr | 0x15d8b00 216 | link | 217 | remote_pid | 0 218 | tls | 219 | application_name | app - 192.168.122.16:56574 220 | 221 | ``` 222 | 223 | *Q: When supporting multiple versions of PgBouncer, how are new/old/renamed columns handled?* 224 | 225 | A: pgbouncer_fdw will return all columns for all supported versions of PgBouncer. This means that there may be columns being returned that have no data because that version of PgBouncer does not have that column. 226 | 227 | If a newer version of PgBouncer drops a column completely, pgbouncer_fdw will support it for a limited time with an empty value and evaluate a time period when support for versions with that old column will be deprecated. 228 | 229 | For example, the application_name column will show up if you are running PgBouncer 1.17, but it will have an empty string for a value. 230 | ``` 231 | postgres=# select * from pgbouncer_clients; 232 | -[ RECORD 1 ]---------+--------------------------- 233 | pgbouncer_target_host | pgbouncer 234 | type | C 235 | user | ccp_monitoring 236 | database | pgbouncer 237 | state | active 238 | addr | 192.168.122.16 239 | port | 53050 240 | local_addr | 192.168.122.13 241 | local_port | 6432 242 | connect_time | 2023-05-12 15:07:35-04 243 | request_time | 2023-05-12 15:07:35-04 244 | wait | 0 245 | wait_us | 0 246 | close_needed | 0 247 | ptr | 0x15d8b00 248 | link | 249 | remote_pid | 0 250 | tls | 251 | application_name | 252 | ``` 253 | 254 | For renamed columns, the newly named column will always be returned and the old column name will not be available no matter the version of PgBouncer you are running. For example, in the `pgbouncer_pools` view for the `SHOW POOLS` command, the old `cl_cancel_req` in v1.17 was renamed to `cl_waiting_cancel_req` in 1.18. This means that for PgBouncer 1.17, you can get the value of `cl_cancel_req` by looking at the value of `cl_waiting_cancel_req`. 255 | 256 | -------------------------------------------------------------------------------- /updates/pgbouncer_fdw--1.3.0--1.4.0.sql: -------------------------------------------------------------------------------- 1 | 2 | -------- 3 | CREATE TEMP TABLE pgbouncer_fdw_preserve_privs_temp (statement text); 4 | 5 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 6 | SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.pgbouncer_databases_func() TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' 7 | FROM information_schema.routine_privileges 8 | WHERE routine_schema = '@extschema@' 9 | AND routine_name = 'pgbouncer_databases_func' 10 | AND grantee != 'PUBLIC'; 11 | 12 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 13 | SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.pgbouncer_users_func() TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' 14 | FROM information_schema.routine_privileges 15 | WHERE routine_schema = '@extschema@' 16 | AND routine_name = 'pgbouncer_users_func' 17 | AND grantee != 'PUBLIC'; 18 | 19 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 20 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_databases TO '||grantee::text||';' 21 | FROM information_schema.table_privileges 22 | WHERE table_schema = '@extschema@' 23 | AND table_name = 'pgbouncer_databases' 24 | AND grantee != 'PUBLIC' 25 | GROUP BY grantee; 26 | 27 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 28 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_users TO '||grantee::text||';' 29 | FROM information_schema.table_privileges 30 | WHERE table_schema = '@extschema@' 31 | AND table_name = 'pgbouncer_users' 32 | AND grantee != 'PUBLIC' 33 | GROUP BY grantee; 34 | 35 | DROP VIEW @extschema@.pgbouncer_databases; 36 | DROP VIEW @extschema@.pgbouncer_users; 37 | 38 | DROP FUNCTION @extschema@.pgbouncer_databases_func(); 39 | DROP FUNCTION @extschema@.pgbouncer_users_func(); 40 | 41 | CREATE FUNCTION @extschema@.pgbouncer_databases_func() RETURNS TABLE 42 | ( 43 | pgbouncer_target_host text 44 | , name text 45 | , host text 46 | , port int 47 | , database text 48 | , force_user text 49 | , pool_size int 50 | , min_pool_size int 51 | , reserve_pool_size int 52 | , server_lifetime int 53 | , pool_mode text 54 | , load_balance_hosts int 55 | , max_connections int 56 | , current_connections int 57 | , max_client_connections int 58 | , current_client_connections int 59 | , paused int 60 | , disabled int 61 | ) 62 | LANGUAGE plpgsql 63 | AS $$ 64 | DECLARE 65 | ex_context text; 66 | ex_detail text; 67 | ex_hint text; 68 | ex_message text; 69 | v_row record; 70 | v_version_major int; 71 | v_version_minor int; 72 | BEGIN 73 | 74 | FOR v_row IN 75 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 76 | LOOP BEGIN 77 | 78 | SELECT version_major, version_minor 79 | INTO v_version_major, v_version_minor 80 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 81 | 82 | IF v_version_major = 1 THEN 83 | IF v_version_minor >= 24 THEN 84 | RETURN QUERY SELECT 85 | v_row.target_host AS pgbouncer_target_host 86 | , x.name 87 | , x.host 88 | , x.port 89 | , x.database 90 | , x.force_user 91 | , x.pool_size 92 | , x.min_pool_size 93 | , x.reserve_pool_size 94 | , x.server_lifetime 95 | , x.pool_mode 96 | , x.load_balance_hosts 97 | , x.max_connections 98 | , x.current_connections 99 | , x.max_client_connections 100 | , x.current_client_connections 101 | , x.paused 102 | , x.disabled 103 | FROM dblink(v_row.target_host, 'show databases') AS x 104 | ( 105 | name text 106 | , host text 107 | , port int 108 | , database text 109 | , force_user text 110 | , pool_size int 111 | , min_pool_size int 112 | , reserve_pool_size int 113 | , server_lifetime int 114 | , pool_mode text 115 | , load_balance_hosts int 116 | , max_connections int 117 | , current_connections int 118 | , max_client_connections int 119 | , current_client_connections int 120 | , paused int 121 | , disabled int 122 | ); 123 | ELSIF v_version_minor = 23 THEN 124 | RETURN QUERY SELECT 125 | v_row.target_host AS pgbouncer_target_host 126 | , x.name 127 | , x.host 128 | , x.port 129 | , x.database 130 | , x.force_user 131 | , x.pool_size 132 | , x.min_pool_size 133 | , x.reserve_pool AS reserve_pool_size 134 | , x.server_lifetime 135 | , x.pool_mode 136 | , 0 AS load_balance_hosts 137 | , x.max_connections 138 | , x.current_connections 139 | , 0 AS max_client_connections 140 | , 0 AS current_client_connections 141 | , x.paused 142 | , x.disabled 143 | FROM dblink(v_row.target_host, 'show databases') AS x 144 | ( 145 | name text 146 | , host text 147 | , port int 148 | , database text 149 | , force_user text 150 | , pool_size int 151 | , min_pool_size int 152 | , reserve_pool int 153 | , server_lifetime int 154 | , pool_mode text 155 | , max_connections int 156 | , current_connections int 157 | , paused int 158 | , disabled int 159 | ); 160 | ELSIF v_version_minor < 23 THEN 161 | RETURN QUERY SELECT 162 | v_row.target_host AS pgbouncer_target_host 163 | , x.name 164 | , x.host 165 | , x.port 166 | , x.database 167 | , x.force_user 168 | , x.pool_size 169 | , x.min_pool_size 170 | , x.reserve_pool AS reserve_pool_size 171 | , 0 AS server_lifetime 172 | , x.pool_mode 173 | , 0 AS load_balance_hosts 174 | , x.max_connections 175 | , x.current_connections 176 | , 0 AS max_client_connections 177 | , 0 AS current_client_connections 178 | , x.paused 179 | , x.disabled 180 | FROM dblink(v_row.target_host, 'show databases') AS x 181 | ( 182 | name text 183 | , host text 184 | , port int 185 | , database text 186 | , force_user text 187 | , pool_size int 188 | , min_pool_size int 189 | , reserve_pool int 190 | , pool_mode text 191 | , max_connections int 192 | , current_connections int 193 | , paused int 194 | , disabled int 195 | ); 196 | END IF; 197 | ELSE 198 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 199 | END IF; 200 | EXCEPTION 201 | WHEN connection_exception THEN 202 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 203 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 204 | ex_context = PG_EXCEPTION_CONTEXT, 205 | ex_detail = PG_EXCEPTION_DETAIL, 206 | ex_hint = PG_EXCEPTION_HINT; 207 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 208 | ORIGINAL ERROR: % 209 | CONTEXT: % 210 | DETAIL: % 211 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 212 | END; 213 | END LOOP; 214 | 215 | END 216 | $$; 217 | 218 | 219 | CREATE VIEW @extschema@.pgbouncer_databases AS 220 | SELECT pgbouncer_target_host 221 | , name 222 | , host 223 | , port 224 | , database 225 | , force_user 226 | , pool_size 227 | , min_pool_size 228 | , reserve_pool_size 229 | , server_lifetime 230 | , pool_mode 231 | , load_balance_hosts 232 | , max_connections 233 | , current_connections 234 | , max_client_connections 235 | , current_client_connections 236 | , paused 237 | , disabled 238 | FROM @extschema@.pgbouncer_databases_func(); 239 | 240 | 241 | CREATE FUNCTION @extschema@.pgbouncer_users_func() RETURNS TABLE 242 | ( 243 | pgbouncer_target_host text 244 | , name text 245 | , pool_size text 246 | , reserve_pool_size text 247 | , pool_mode text 248 | , max_user_connections int 249 | , current_connections int 250 | , max_user_client_connections int 251 | , current_client_connections int 252 | ) 253 | LANGUAGE plpgsql 254 | AS $$ 255 | DECLARE 256 | ex_context text; 257 | ex_detail text; 258 | ex_hint text; 259 | ex_message text; 260 | v_row record; 261 | v_version_major int; 262 | v_version_minor int; 263 | BEGIN 264 | 265 | FOR v_row IN 266 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 267 | LOOP BEGIN 268 | 269 | SELECT version_major, version_minor 270 | INTO v_version_major, v_version_minor 271 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 272 | 273 | IF v_version_major = 1 THEN 274 | IF v_version_minor >= 24 THEN 275 | RETURN QUERY SELECT 276 | v_row.target_host AS pgbouncer_target_host 277 | , x.name 278 | , x.pool_size 279 | , x.reserve_pool_size 280 | , x.pool_mode 281 | , x.max_user_connections 282 | , x.current_connections 283 | , x.max_user_client_connections 284 | , x.current_client_connections 285 | FROM dblink(v_row.target_host, 'show users') AS x 286 | ( 287 | name text 288 | , pool_size text 289 | , reserve_pool_size text 290 | , pool_mode text 291 | , max_user_connections int 292 | , current_connections int 293 | , max_user_client_connections int 294 | , current_client_connections int 295 | ); 296 | ELSIF v_version_minor = 23 THEN 297 | RETURN QUERY SELECT 298 | v_row.target_host AS pgbouncer_target_host 299 | , x.name 300 | , x.pool_size 301 | , '' AS reserve_pool_size 302 | , x.pool_mode 303 | , x.max_user_connections 304 | , x.current_connections 305 | , 0 AS max_user_client_connections 306 | , 0 AS current_client_connections 307 | FROM dblink(v_row.target_host, 'show users') AS x 308 | ( 309 | name text 310 | , pool_size text 311 | , pool_mode text 312 | , max_user_connections int 313 | , current_connections int 314 | ); 315 | ELSIF v_version_minor < 23 THEN 316 | RETURN QUERY SELECT 317 | v_row.target_host AS pgbouncer_target_host 318 | , x.name 319 | , '' AS pool_size 320 | , '' AS reserve_pool_size 321 | , x.pool_mode 322 | , 0 AS max_user_connections 323 | , 0 AS current_connections 324 | , 0 AS max_user_client_connections 325 | , 0 AS current_client_connections 326 | FROM dblink(v_row.target_host, 'show users') AS x 327 | ( 328 | name text 329 | , pool_mode text 330 | ); 331 | END IF; 332 | ELSE 333 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 334 | END IF; 335 | EXCEPTION 336 | WHEN connection_exception THEN 337 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 338 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 339 | ex_context = PG_EXCEPTION_CONTEXT, 340 | ex_detail = PG_EXCEPTION_DETAIL, 341 | ex_hint = PG_EXCEPTION_HINT; 342 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 343 | ORIGINAL ERROR: % 344 | CONTEXT: % 345 | DETAIL: % 346 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 347 | END; 348 | END LOOP; 349 | END 350 | $$; 351 | 352 | 353 | CREATE VIEW @extschema@.pgbouncer_users AS 354 | SELECT pgbouncer_target_host 355 | , name 356 | , pool_size 357 | , reserve_pool_size 358 | , pool_mode 359 | , max_user_connections 360 | , current_connections 361 | , max_user_client_connections 362 | , current_client_connections 363 | FROM @extschema@.pgbouncer_users_func(); 364 | 365 | -- Restore dropped object privileges 366 | DO $$ 367 | DECLARE 368 | v_row record; 369 | BEGIN 370 | FOR v_row IN SELECT statement FROM pgbouncer_fdw_preserve_privs_temp LOOP 371 | IF v_row.statement IS NOT NULL THEN 372 | EXECUTE v_row.statement; 373 | END IF; 374 | END LOOP; 375 | END 376 | $$; 377 | 378 | DROP TABLE IF EXISTS pgbouncer_fdw_preserve_privs_temp; 379 | -------------------------------------------------------------------------------- /updates/pgbouncer_fdw--1.0.1--1.1.0.sql: -------------------------------------------------------------------------------- 1 | CREATE TEMP TABLE pgbouncer_fdw_preserve_privs_temp (statement text); 2 | 3 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 4 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_clients TO '||grantee::text||';' 5 | FROM information_schema.table_privileges 6 | WHERE table_schema = '@extschema@' 7 | AND table_name = 'pgbouncer_clients' 8 | GROUP BY grantee; 9 | 10 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 11 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_servers TO '||grantee::text||';' 12 | FROM information_schema.table_privileges 13 | WHERE table_schema = '@extschema@' 14 | AND table_name = 'pgbouncer_servers' 15 | GROUP BY grantee; 16 | 17 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 18 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_sockets TO '||grantee::text||';' 19 | FROM information_schema.table_privileges 20 | WHERE table_schema = '@extschema@' 21 | AND table_name = 'pgbouncer_sockets' 22 | GROUP BY grantee; 23 | 24 | DROP VIEW @extschema@.pgbouncer_clients; 25 | DROP VIEW @extschema@.pgbouncer_servers; 26 | DROP VIEW @extschema@.pgbouncer_sockets; 27 | 28 | 29 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 30 | SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.pgbouncer_clients_func() TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' 31 | FROM information_schema.routine_privileges 32 | WHERE routine_schema = '@extschema@' 33 | AND routine_name = 'pgbouncer_clients_func'; 34 | 35 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 36 | SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.pgbouncer_servers_func() TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' 37 | FROM information_schema.routine_privileges 38 | WHERE routine_schema = '@extschema@' 39 | AND routine_name = 'pgbouncer_servers_func'; 40 | 41 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 42 | SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.pgbouncer_sockets_func() TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' 43 | FROM information_schema.routine_privileges 44 | WHERE routine_schema = '@extschema@' 45 | AND routine_name = 'pgbouncer_sockets_func'; 46 | 47 | DROP FUNCTION @extschema@.pgbouncer_clients_func(); 48 | DROP FUNCTION @extschema@.pgbouncer_servers_func(); 49 | DROP FUNCTION @extschema@.pgbouncer_sockets_func(); 50 | 51 | 52 | CREATE FUNCTION @extschema@.pgbouncer_clients_func() RETURNS TABLE 53 | ( 54 | pgbouncer_target_host text 55 | , "type" text 56 | , "user" text 57 | , database text 58 | , state text 59 | , addr text 60 | , port int 61 | , local_addr text 62 | , local_port int 63 | , connect_time timestamp with time zone 64 | , request_time timestamp with time zone 65 | , wait int 66 | , wait_us int 67 | , close_needed int 68 | , ptr text 69 | , link text 70 | , remote_pid int 71 | , tls text 72 | , application_name text 73 | , prepared_statements int 74 | ) 75 | LANGUAGE plpgsql 76 | AS $$ 77 | DECLARE 78 | ex_context text; 79 | ex_detail text; 80 | ex_hint text; 81 | ex_message text; 82 | v_row record; 83 | v_version_major int; 84 | v_version_minor int; 85 | BEGIN 86 | 87 | FOR v_row IN 88 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 89 | LOOP BEGIN 90 | 91 | SELECT version_major, version_minor 92 | INTO v_version_major, v_version_minor 93 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 94 | 95 | IF v_version_major >= 1 AND v_version_minor >= 21 THEN 96 | RETURN QUERY SELECT 97 | v_row.target_host AS pgbouncer_target_host 98 | , x."type" 99 | , x."user" 100 | , x.database 101 | , x.state 102 | , x.addr 103 | , x.port 104 | , x.local_addr 105 | , x.local_port 106 | , x.connect_time 107 | , x.request_time 108 | , x.wait 109 | , x.wait_us 110 | , x.close_needed 111 | , x.ptr 112 | , x.link 113 | , x.remote_pid 114 | , x.tls 115 | , x.application_name 116 | , x.prepared_statements 117 | FROM dblink(v_row.target_host, 'show clients') AS x 118 | ( "type" text 119 | , "user" text 120 | , database text 121 | , state text 122 | , addr text 123 | , port int 124 | , local_addr text 125 | , local_port int 126 | , connect_time timestamp with time zone 127 | , request_time timestamp with time zone 128 | , wait int 129 | , wait_us int 130 | , close_needed int 131 | , ptr text 132 | , link text 133 | , remote_pid int 134 | , tls text 135 | , application_name text 136 | , prepared_statements int 137 | ); 138 | ELSIF v_version_major = 1 AND v_version_minor >= 18 AND v_version_minor < 21 THEN 139 | RETURN QUERY SELECT 140 | v_row.target_host AS pgbouncer_target_host 141 | , x."type" 142 | , x."user" 143 | , x.database 144 | , x.state 145 | , x.addr 146 | , x.port 147 | , x.local_addr 148 | , x.local_port 149 | , x.connect_time 150 | , x.request_time 151 | , x.wait 152 | , x.wait_us 153 | , x.close_needed 154 | , x.ptr 155 | , x.link 156 | , x.remote_pid 157 | , x.tls 158 | , x.application_name 159 | , 0 AS prepared_statements 160 | FROM dblink(v_row.target_host, 'show clients') AS x 161 | ( "type" text 162 | , "user" text 163 | , database text 164 | , state text 165 | , addr text 166 | , port int 167 | , local_addr text 168 | , local_port int 169 | , connect_time timestamp with time zone 170 | , request_time timestamp with time zone 171 | , wait int 172 | , wait_us int 173 | , close_needed int 174 | , ptr text 175 | , link text 176 | , remote_pid int 177 | , tls text 178 | , application_name text 179 | ); 180 | -- backward compatiblity floor is 1.17 181 | ELSIF v_version_major = 1 AND v_version_minor = 17 THEN 182 | RETURN QUERY SELECT 183 | v_row.target_host AS pgbouncer_target_host 184 | , x."type" 185 | , x."user" 186 | , x.database 187 | , x.state 188 | , x.addr 189 | , x.port 190 | , x.local_addr 191 | , x.local_port 192 | , x.connect_time 193 | , x.request_time 194 | , x.wait 195 | , x.wait_us 196 | , x.close_needed 197 | , x.ptr 198 | , x.link 199 | , x.remote_pid 200 | , x.tls 201 | , '' AS application_name 202 | , 0 AS prepared_statements 203 | FROM dblink(v_row.target_host, 'show clients') AS x 204 | ( "type" text 205 | , "user" text 206 | , database text 207 | , state text 208 | , addr text 209 | , port int 210 | , local_addr text 211 | , local_port int 212 | , connect_time timestamp with time zone 213 | , request_time timestamp with time zone 214 | , wait int 215 | , wait_us int 216 | , close_needed int 217 | , ptr text 218 | , link text 219 | , remote_pid int 220 | , tls text 221 | ); 222 | ELSE 223 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 224 | END IF; 225 | EXCEPTION 226 | WHEN connection_exception THEN 227 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 228 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 229 | ex_context = PG_EXCEPTION_CONTEXT, 230 | ex_detail = PG_EXCEPTION_DETAIL, 231 | ex_hint = PG_EXCEPTION_HINT; 232 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 233 | ORIGINAL ERROR: % 234 | CONTEXT: % 235 | DETAIL: % 236 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 237 | END; 238 | END LOOP; 239 | 240 | END 241 | $$; 242 | 243 | 244 | CREATE FUNCTION @extschema@.pgbouncer_servers_func() RETURNS TABLE 245 | ( 246 | pgbouncer_target_host text 247 | , "type" text 248 | , "user" text 249 | , database text 250 | , state text 251 | , addr text 252 | , port int 253 | , local_addr text 254 | , local_port int 255 | , connect_time timestamp with time zone 256 | , request_time timestamp with time zone 257 | , wait int 258 | , wait_us int 259 | , close_needed int 260 | , ptr text 261 | , link text 262 | , remote_pid int 263 | , tls text 264 | , application_name text 265 | , prepared_statements int 266 | ) 267 | LANGUAGE plpgsql 268 | AS $$ 269 | DECLARE 270 | ex_context text; 271 | ex_detail text; 272 | ex_hint text; 273 | ex_message text; 274 | v_row record; 275 | v_version_major int; 276 | v_version_minor int; 277 | BEGIN 278 | 279 | FOR v_row IN 280 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 281 | LOOP BEGIN 282 | 283 | SELECT version_major, version_minor 284 | INTO v_version_major, v_version_minor 285 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 286 | 287 | IF v_version_major >= 1 AND v_version_minor >= 21 THEN 288 | RETURN QUERY SELECT 289 | v_row.target_host AS pgbouncer_target_host 290 | , x."type" 291 | , x."user" 292 | , x.database 293 | , x.state 294 | , x.addr 295 | , x.port 296 | , x.local_addr 297 | , x.local_port 298 | , x.connect_time 299 | , x.request_time 300 | , x.wait 301 | , x.wait_us 302 | , x.close_needed 303 | , x.ptr 304 | , x.link 305 | , x.remote_pid 306 | , x.tls 307 | , x.application_name 308 | , x.prepared_statements 309 | FROM dblink(v_row.target_host, 'show servers') AS x 310 | ( 311 | "type" text 312 | , "user" text 313 | , database text 314 | , state text 315 | , addr text 316 | , port int 317 | , local_addr text 318 | , local_port int 319 | , connect_time timestamp with time zone 320 | , request_time timestamp with time zone 321 | , wait int 322 | , wait_us int 323 | , close_needed int 324 | , ptr text 325 | , link text 326 | , remote_pid int 327 | , tls text 328 | , application_name text 329 | , prepared_statements int 330 | ); 331 | ELSIF v_version_major = 1 AND v_version_minor >= 18 and v_version_minor < 21 THEN 332 | RETURN QUERY SELECT 333 | v_row.target_host AS pgbouncer_target_host 334 | , x."type" 335 | , x."user" 336 | , x.database 337 | , x.state 338 | , x.addr 339 | , x.port 340 | , x.local_addr 341 | , x.local_port 342 | , x.connect_time 343 | , x.request_time 344 | , x.wait 345 | , x.wait_us 346 | , x.close_needed 347 | , x.ptr 348 | , x.link 349 | , x.remote_pid 350 | , x.tls 351 | , x.application_name 352 | , 0 AS prepared_statements 353 | FROM dblink(v_row.target_host, 'show servers') AS x 354 | ( 355 | "type" text 356 | , "user" text 357 | , database text 358 | , state text 359 | , addr text 360 | , port int 361 | , local_addr text 362 | , local_port int 363 | , connect_time timestamp with time zone 364 | , request_time timestamp with time zone 365 | , wait int 366 | , wait_us int 367 | , close_needed int 368 | , ptr text 369 | , link text 370 | , remote_pid int 371 | , tls text 372 | , application_name text 373 | ); 374 | -- backward compatiblity floor is 1.17 375 | ELSIF v_version_major = 1 AND v_version_minor = 17 THEN 376 | RETURN QUERY SELECT 377 | v_row.target_host AS pgbouncer_target_host 378 | , x."type" 379 | , x."user" 380 | , x.database 381 | , x.state 382 | , x.addr 383 | , x.port 384 | , x.local_addr 385 | , x.local_port 386 | , x.connect_time 387 | , x.request_time 388 | , x.wait 389 | , x.wait_us 390 | , x.close_needed 391 | , x.ptr 392 | , x.link 393 | , x.remote_pid 394 | , x.tls 395 | , '' AS application_name 396 | , 0 AS prepared_statements 397 | FROM dblink(v_row.target_host, 'show servers') AS x 398 | ( 399 | "type" text 400 | , "user" text 401 | , database text 402 | , state text 403 | , addr text 404 | , port int 405 | , local_addr text 406 | , local_port int 407 | , connect_time timestamp with time zone 408 | , request_time timestamp with time zone 409 | , wait int 410 | , wait_us int 411 | , close_needed int 412 | , ptr text 413 | , link text 414 | , remote_pid int 415 | , tls text 416 | ); 417 | ELSE 418 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 419 | END IF; 420 | EXCEPTION 421 | WHEN connection_exception THEN 422 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 423 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 424 | ex_context = PG_EXCEPTION_CONTEXT, 425 | ex_detail = PG_EXCEPTION_DETAIL, 426 | ex_hint = PG_EXCEPTION_HINT; 427 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 428 | ORIGINAL ERROR: % 429 | CONTEXT: % 430 | DETAIL: % 431 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 432 | END; 433 | END LOOP; 434 | 435 | END 436 | $$; 437 | 438 | 439 | CREATE FUNCTION @extschema@.pgbouncer_sockets_func() RETURNS TABLE 440 | ( 441 | pgbouncer_target_host text 442 | , "type" text 443 | , "user" text 444 | , database text 445 | , state text 446 | , addr text 447 | , port int 448 | , local_addr text 449 | , local_port int 450 | , connect_time timestamp with time zone 451 | , request_time timestamp with time zone 452 | , wait int 453 | , wait_us int 454 | , close_needed int 455 | , ptr text 456 | , link text 457 | , remote_pid int 458 | , tls text 459 | , application_name text 460 | , recv_pos int 461 | , pkt_pos int 462 | , pkt_remain int 463 | , send_pos int 464 | , send_remain int 465 | , pkt_avail int 466 | , send_avail int 467 | , prepared_statements int 468 | ) 469 | LANGUAGE plpgsql 470 | AS $$ 471 | DECLARE 472 | ex_context text; 473 | ex_detail text; 474 | ex_hint text; 475 | ex_message text; 476 | v_row record; 477 | v_version_major int; 478 | v_version_minor int; 479 | BEGIN 480 | 481 | FOR v_row IN 482 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 483 | LOOP BEGIN 484 | SELECT version_major, version_minor 485 | INTO v_version_major, v_version_minor 486 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 487 | 488 | IF v_version_major >= 1 AND v_version_minor >= 21 THEN 489 | RETURN QUERY SELECT 490 | v_row.target_host AS pgbouncer_target_host 491 | , x."type" 492 | , x."user" 493 | , x.database 494 | , x.state 495 | , x.addr 496 | , x.port 497 | , x.local_addr 498 | , x.local_port 499 | , x.connect_time 500 | , x.request_time 501 | , x.wait 502 | , x.wait_us 503 | , x.close_needed 504 | , x.ptr 505 | , x.link 506 | , x.remote_pid 507 | , x.tls 508 | , x.application_name 509 | , x.recv_pos 510 | , x.pkt_pos 511 | , x.pkt_remain 512 | , x.send_pos 513 | , x.send_remain 514 | , x.pkt_avail 515 | , x.send_avail 516 | , x.prepared_statements 517 | FROM dblink(v_row.target_host, 'show sockets') AS x 518 | ( 519 | "type" text 520 | , "user" text 521 | , database text 522 | , state text 523 | , addr text 524 | , port int 525 | , local_addr text 526 | , local_port int 527 | , connect_time timestamp with time zone 528 | , request_time timestamp with time zone 529 | , wait int 530 | , wait_us int 531 | , close_needed int 532 | , ptr text 533 | , link text 534 | , remote_pid int 535 | , tls text 536 | , application_name text 537 | , recv_pos int 538 | , pkt_pos int 539 | , pkt_remain int 540 | , send_pos int 541 | , send_remain int 542 | , pkt_avail int 543 | , send_avail int 544 | , prepared_statements int 545 | ); 546 | ELSIF v_version_major = 1 AND v_version_minor >= 18 AND v_version_minor < 21 THEN 547 | RETURN QUERY SELECT 548 | v_row.target_host AS pgbouncer_target_host 549 | , x."type" 550 | , x."user" 551 | , x.database 552 | , x.state 553 | , x.addr 554 | , x.port 555 | , x.local_addr 556 | , x.local_port 557 | , x.connect_time 558 | , x.request_time 559 | , x.wait 560 | , x.wait_us 561 | , x.close_needed 562 | , x.ptr 563 | , x.link 564 | , x.remote_pid 565 | , x.tls 566 | , x.application_name 567 | , x.recv_pos 568 | , x.pkt_pos 569 | , x.pkt_remain 570 | , x.send_pos 571 | , x.send_remain 572 | , x.pkt_avail 573 | , x.send_avail 574 | , 0 AS prepared_statements 575 | FROM dblink(v_row.target_host, 'show sockets') AS x 576 | ( 577 | "type" text 578 | , "user" text 579 | , database text 580 | , state text 581 | , addr text 582 | , port int 583 | , local_addr text 584 | , local_port int 585 | , connect_time timestamp with time zone 586 | , request_time timestamp with time zone 587 | , wait int 588 | , wait_us int 589 | , close_needed int 590 | , ptr text 591 | , link text 592 | , remote_pid int 593 | , tls text 594 | , application_name text 595 | , recv_pos int 596 | , pkt_pos int 597 | , pkt_remain int 598 | , send_pos int 599 | , send_remain int 600 | , pkt_avail int 601 | , send_avail int 602 | ); 603 | -- backward compatiblity floor is 1.17 604 | ELSIF v_version_major = 1 AND v_version_minor = 17 THEN 605 | RETURN QUERY SELECT 606 | v_row.target_host AS pgbouncer_target_host 607 | , x."type" 608 | , x."user" 609 | , x.database 610 | , x.state 611 | , x.addr 612 | , x.port 613 | , x.local_addr 614 | , x.local_port 615 | , x.connect_time 616 | , x.request_time 617 | , x.wait 618 | , x.wait_us 619 | , x.close_needed 620 | , x.ptr 621 | , x.link 622 | , x.remote_pid 623 | , x.tls 624 | , '' AS application_name 625 | , x.recv_pos 626 | , x.pkt_pos 627 | , x.pkt_remain 628 | , x.send_pos 629 | , x.send_remain 630 | , x.pkt_avail 631 | , x.send_avail 632 | , 0 AS prepared_statements 633 | FROM dblink(v_row.target_host, 'show sockets') AS x 634 | ( 635 | "type" text 636 | , "user" text 637 | , database text 638 | , state text 639 | , addr text 640 | , port int 641 | , local_addr text 642 | , local_port int 643 | , connect_time timestamp with time zone 644 | , request_time timestamp with time zone 645 | , wait int 646 | , wait_us int 647 | , close_needed int 648 | , ptr text 649 | , link text 650 | , remote_pid int 651 | , tls text 652 | , recv_pos int 653 | , pkt_pos int 654 | , pkt_remain int 655 | , send_pos int 656 | , send_remain int 657 | , pkt_avail int 658 | , send_avail int 659 | ); 660 | ELSE 661 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 662 | END IF; 663 | EXCEPTION 664 | WHEN connection_exception THEN 665 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 666 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 667 | ex_context = PG_EXCEPTION_CONTEXT, 668 | ex_detail = PG_EXCEPTION_DETAIL, 669 | ex_hint = PG_EXCEPTION_HINT; 670 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 671 | ORIGINAL ERROR: % 672 | CONTEXT: % 673 | DETAIL: % 674 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 675 | END; 676 | END LOOP; 677 | 678 | END 679 | $$; 680 | 681 | 682 | CREATE VIEW @extschema@.pgbouncer_clients AS 683 | SELECT pgbouncer_target_host 684 | , "type" 685 | , "user" 686 | , database 687 | , state 688 | , addr 689 | , port 690 | , local_addr 691 | , local_port 692 | , connect_time 693 | , request_time 694 | , wait 695 | , wait_us 696 | , close_needed 697 | , ptr 698 | , link 699 | , remote_pid 700 | , tls 701 | , application_name 702 | , prepared_statements 703 | FROM @extschema@.pgbouncer_clients_func(); 704 | 705 | 706 | CREATE VIEW @extschema@.pgbouncer_servers AS 707 | SELECT pgbouncer_target_host 708 | , "type" 709 | , "user" 710 | , database 711 | , state 712 | , addr 713 | , port 714 | , local_addr 715 | , local_port 716 | , connect_time 717 | , request_time 718 | , wait 719 | , wait_us 720 | , close_needed 721 | , ptr 722 | , link 723 | , remote_pid 724 | , tls 725 | , application_name 726 | , prepared_statements 727 | FROM @extschema@.pgbouncer_servers_func(); 728 | 729 | 730 | CREATE VIEW @extschema@.pgbouncer_sockets AS 731 | SELECT pgbouncer_target_host 732 | , "type" 733 | , "user" 734 | , database 735 | , state 736 | , addr 737 | , port 738 | , local_addr 739 | , local_port 740 | , connect_time 741 | , request_time 742 | , wait 743 | , wait_us 744 | , close_needed 745 | , ptr 746 | , link 747 | , remote_pid 748 | , tls 749 | , application_name 750 | , recv_pos 751 | , pkt_pos 752 | , pkt_remain 753 | , send_pos 754 | , send_remain 755 | , pkt_avail 756 | , send_avail 757 | , prepared_statements 758 | FROM @extschema@.pgbouncer_sockets_func(); 759 | 760 | -------------------------------------------------------------------------------- /updates/pgbouncer_fdw--1.1.0--1.2.0.sql: -------------------------------------------------------------------------------- 1 | CREATE TEMP TABLE pgbouncer_fdw_preserve_privs_temp (statement text); 2 | 3 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 4 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_clients TO '||grantee::text||';' 5 | FROM information_schema.table_privileges 6 | WHERE table_schema = '@extschema@' 7 | AND table_name = 'pgbouncer_clients' 8 | AND grantee != 'PUBLIC' 9 | GROUP BY grantee; 10 | 11 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 12 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_servers TO '||grantee::text||';' 13 | FROM information_schema.table_privileges 14 | WHERE table_schema = '@extschema@' 15 | AND table_name = 'pgbouncer_servers' 16 | AND grantee != 'PUBLIC' 17 | GROUP BY grantee; 18 | 19 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 20 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_sockets TO '||grantee::text||';' 21 | FROM information_schema.table_privileges 22 | WHERE table_schema = '@extschema@' 23 | AND table_name = 'pgbouncer_sockets' 24 | AND grantee != 'PUBLIC' 25 | GROUP BY grantee; 26 | 27 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 28 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_databases TO '||grantee::text||';' 29 | FROM information_schema.table_privileges 30 | WHERE table_schema = '@extschema@' 31 | AND table_name = 'pgbouncer_databases' 32 | AND grantee != 'PUBLIC' 33 | GROUP BY grantee; 34 | 35 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 36 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_stats TO '||grantee::text||';' 37 | FROM information_schema.table_privileges 38 | WHERE table_schema = '@extschema@' 39 | AND table_name = 'pgbouncer_stats' 40 | AND grantee != 'PUBLIC' 41 | GROUP BY grantee; 42 | 43 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 44 | SELECT 'GRANT '||string_agg(privilege_type, ',')||' ON @extschema@.pgbouncer_users TO '||grantee::text||';' 45 | FROM information_schema.table_privileges 46 | WHERE table_schema = '@extschema@' 47 | AND table_name = 'pgbouncer_users' 48 | AND grantee != 'PUBLIC' 49 | GROUP BY grantee; 50 | 51 | DROP VIEW @extschema@.pgbouncer_clients; 52 | DROP VIEW @extschema@.pgbouncer_servers; 53 | DROP VIEW @extschema@.pgbouncer_sockets; 54 | DROP VIEW @extschema@.pgbouncer_databases; 55 | DROP VIEW @extschema@.pgbouncer_stats; 56 | DROP VIEW @extschema@.pgbouncer_users; 57 | 58 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 59 | SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.pgbouncer_clients_func() TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' 60 | FROM information_schema.routine_privileges 61 | WHERE routine_schema = '@extschema@' 62 | AND routine_name = 'pgbouncer_clients_func' 63 | AND grantee != 'PUBLIC'; 64 | 65 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 66 | SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.pgbouncer_servers_func() TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' 67 | FROM information_schema.routine_privileges 68 | WHERE routine_schema = '@extschema@' 69 | AND routine_name = 'pgbouncer_servers_func' 70 | AND grantee != 'PUBLIC'; 71 | 72 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 73 | SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.pgbouncer_sockets_func() TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' 74 | FROM information_schema.routine_privileges 75 | WHERE routine_schema = '@extschema@' 76 | AND routine_name = 'pgbouncer_sockets_func' 77 | AND grantee != 'PUBLIC'; 78 | 79 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 80 | SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.pgbouncer_databases_func() TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' 81 | FROM information_schema.routine_privileges 82 | WHERE routine_schema = '@extschema@' 83 | AND routine_name = 'pgbouncer_databases_func' 84 | AND grantee != 'PUBLIC'; 85 | 86 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 87 | SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.pgbouncer_stats_func() TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' 88 | FROM information_schema.routine_privileges 89 | WHERE routine_schema = '@extschema@' 90 | AND routine_name = 'pgbouncer_stats_func' 91 | AND grantee != 'PUBLIC'; 92 | 93 | INSERT INTO pgbouncer_fdw_preserve_privs_temp 94 | SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.pgbouncer_users_func() TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' 95 | FROM information_schema.routine_privileges 96 | WHERE routine_schema = '@extschema@' 97 | AND routine_name = 'pgbouncer_users_func' 98 | AND grantee != 'PUBLIC'; 99 | 100 | DROP FUNCTION @extschema@.pgbouncer_clients_func(); 101 | DROP FUNCTION @extschema@.pgbouncer_servers_func(); 102 | DROP FUNCTION @extschema@.pgbouncer_sockets_func(); 103 | DROP FUNCTION @extschema@.pgbouncer_databases_func(); 104 | DROP FUNCTION @extschema@.pgbouncer_stats_func(); 105 | DROP FUNCTION @extschema@.pgbouncer_users_func(); 106 | 107 | CREATE FUNCTION @extschema@.pgbouncer_clients_func() RETURNS TABLE 108 | ( 109 | pgbouncer_target_host text 110 | , "type" text 111 | , "user" text 112 | , database text 113 | , replication text 114 | , state text 115 | , addr text 116 | , port int 117 | , local_addr text 118 | , local_port int 119 | , connect_time timestamp with time zone 120 | , request_time timestamp with time zone 121 | , wait int 122 | , wait_us int 123 | , close_needed int 124 | , ptr text 125 | , link text 126 | , remote_pid int 127 | , tls text 128 | , application_name text 129 | , prepared_statements int 130 | ) 131 | LANGUAGE plpgsql 132 | AS $$ 133 | DECLARE 134 | ex_context text; 135 | ex_detail text; 136 | ex_hint text; 137 | ex_message text; 138 | v_row record; 139 | v_version_major int; 140 | v_version_minor int; 141 | BEGIN 142 | 143 | FOR v_row IN 144 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 145 | LOOP BEGIN 146 | 147 | SELECT version_major, version_minor 148 | INTO v_version_major, v_version_minor 149 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 150 | 151 | IF v_version_major >= 1 AND v_version_minor >= 23 THEN 152 | RETURN QUERY SELECT 153 | v_row.target_host AS pgbouncer_target_host 154 | , x."type" 155 | , x."user" 156 | , x.database 157 | , x.replication 158 | , x.state 159 | , x.addr 160 | , x.port 161 | , x.local_addr 162 | , x.local_port 163 | , x.connect_time 164 | , x.request_time 165 | , x.wait 166 | , x.wait_us 167 | , x.close_needed 168 | , x.ptr 169 | , x.link 170 | , x.remote_pid 171 | , x.tls 172 | , x.application_name 173 | , x.prepared_statements 174 | FROM dblink(v_row.target_host, 'show clients') AS x 175 | ( "type" text 176 | , "user" text 177 | , database text 178 | , replication text 179 | , state text 180 | , addr text 181 | , port int 182 | , local_addr text 183 | , local_port int 184 | , connect_time timestamp with time zone 185 | , request_time timestamp with time zone 186 | , wait int 187 | , wait_us int 188 | , close_needed int 189 | , ptr text 190 | , link text 191 | , remote_pid int 192 | , tls text 193 | , application_name text 194 | , prepared_statements int 195 | ); 196 | ELSIF v_version_major = 1 AND v_version_minor >= 21 and v_version_minor < 23 THEN 197 | RETURN QUERY SELECT 198 | v_row.target_host AS pgbouncer_target_host 199 | , x."type" 200 | , x."user" 201 | , x.database 202 | , '' AS replication 203 | , x.state 204 | , x.addr 205 | , x.port 206 | , x.local_addr 207 | , x.local_port 208 | , x.connect_time 209 | , x.request_time 210 | , x.wait 211 | , x.wait_us 212 | , x.close_needed 213 | , x.ptr 214 | , x.link 215 | , x.remote_pid 216 | , x.tls 217 | , x.application_name 218 | , x.prepared_statements 219 | FROM dblink(v_row.target_host, 'show clients') AS x 220 | ( "type" text 221 | , "user" text 222 | , database text 223 | , state text 224 | , addr text 225 | , port int 226 | , local_addr text 227 | , local_port int 228 | , connect_time timestamp with time zone 229 | , request_time timestamp with time zone 230 | , wait int 231 | , wait_us int 232 | , close_needed int 233 | , ptr text 234 | , link text 235 | , remote_pid int 236 | , tls text 237 | , application_name text 238 | , prepared_statements int 239 | ); 240 | ELSIF v_version_major = 1 AND v_version_minor >= 18 AND v_version_minor < 21 THEN 241 | RETURN QUERY SELECT 242 | v_row.target_host AS pgbouncer_target_host 243 | , x."type" 244 | , x."user" 245 | , x.database 246 | , '' AS replication 247 | , x.state 248 | , x.addr 249 | , x.port 250 | , x.local_addr 251 | , x.local_port 252 | , x.connect_time 253 | , x.request_time 254 | , x.wait 255 | , x.wait_us 256 | , x.close_needed 257 | , x.ptr 258 | , x.link 259 | , x.remote_pid 260 | , x.tls 261 | , x.application_name 262 | , 0 AS prepared_statements 263 | FROM dblink(v_row.target_host, 'show clients') AS x 264 | ( "type" text 265 | , "user" text 266 | , database text 267 | , state text 268 | , addr text 269 | , port int 270 | , local_addr text 271 | , local_port int 272 | , connect_time timestamp with time zone 273 | , request_time timestamp with time zone 274 | , wait int 275 | , wait_us int 276 | , close_needed int 277 | , ptr text 278 | , link text 279 | , remote_pid int 280 | , tls text 281 | , application_name text 282 | ); 283 | -- backward compatiblity floor is 1.17 284 | ELSIF v_version_major = 1 AND v_version_minor = 17 THEN 285 | RETURN QUERY SELECT 286 | v_row.target_host AS pgbouncer_target_host 287 | , x."type" 288 | , x."user" 289 | , x.database 290 | , '' AS replication 291 | , x.state 292 | , x.addr 293 | , x.port 294 | , x.local_addr 295 | , x.local_port 296 | , x.connect_time 297 | , x.request_time 298 | , x.wait 299 | , x.wait_us 300 | , x.close_needed 301 | , x.ptr 302 | , x.link 303 | , x.remote_pid 304 | , x.tls 305 | , '' AS application_name 306 | , 0 AS prepared_statements 307 | FROM dblink(v_row.target_host, 'show clients') AS x 308 | ( "type" text 309 | , "user" text 310 | , database text 311 | , state text 312 | , addr text 313 | , port int 314 | , local_addr text 315 | , local_port int 316 | , connect_time timestamp with time zone 317 | , request_time timestamp with time zone 318 | , wait int 319 | , wait_us int 320 | , close_needed int 321 | , ptr text 322 | , link text 323 | , remote_pid int 324 | , tls text 325 | ); 326 | ELSE 327 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 328 | END IF; 329 | EXCEPTION 330 | WHEN connection_exception THEN 331 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 332 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 333 | ex_context = PG_EXCEPTION_CONTEXT, 334 | ex_detail = PG_EXCEPTION_DETAIL, 335 | ex_hint = PG_EXCEPTION_HINT; 336 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 337 | ORIGINAL ERROR: % 338 | CONTEXT: % 339 | DETAIL: % 340 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 341 | END; 342 | END LOOP; 343 | 344 | END 345 | $$; 346 | 347 | 348 | CREATE FUNCTION @extschema@.pgbouncer_servers_func() RETURNS TABLE 349 | ( 350 | pgbouncer_target_host text 351 | , "type" text 352 | , "user" text 353 | , database text 354 | , replication text 355 | , state text 356 | , addr text 357 | , port int 358 | , local_addr text 359 | , local_port int 360 | , connect_time timestamp with time zone 361 | , request_time timestamp with time zone 362 | , wait int 363 | , wait_us int 364 | , close_needed int 365 | , ptr text 366 | , link text 367 | , remote_pid int 368 | , tls text 369 | , application_name text 370 | , prepared_statements int 371 | ) 372 | LANGUAGE plpgsql 373 | AS $$ 374 | DECLARE 375 | ex_context text; 376 | ex_detail text; 377 | ex_hint text; 378 | ex_message text; 379 | v_row record; 380 | v_version_major int; 381 | v_version_minor int; 382 | BEGIN 383 | 384 | FOR v_row IN 385 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 386 | LOOP BEGIN 387 | 388 | SELECT version_major, version_minor 389 | INTO v_version_major, v_version_minor 390 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 391 | 392 | IF v_version_major >= 1 AND v_version_minor >= 23 THEN 393 | RETURN QUERY SELECT 394 | v_row.target_host AS pgbouncer_target_host 395 | , x."type" 396 | , x."user" 397 | , x.database 398 | , x.replication 399 | , x.state 400 | , x.addr 401 | , x.port 402 | , x.local_addr 403 | , x.local_port 404 | , x.connect_time 405 | , x.request_time 406 | , x.wait 407 | , x.wait_us 408 | , x.close_needed 409 | , x.ptr 410 | , x.link 411 | , x.remote_pid 412 | , x.tls 413 | , x.application_name 414 | , x.prepared_statements 415 | FROM dblink(v_row.target_host, 'show servers') AS x 416 | ( 417 | "type" text 418 | , "user" text 419 | , database text 420 | , replication text 421 | , state text 422 | , addr text 423 | , port int 424 | , local_addr text 425 | , local_port int 426 | , connect_time timestamp with time zone 427 | , request_time timestamp with time zone 428 | , wait int 429 | , wait_us int 430 | , close_needed int 431 | , ptr text 432 | , link text 433 | , remote_pid int 434 | , tls text 435 | , application_name text 436 | , prepared_statements int 437 | ); 438 | ELSIF v_version_major = 1 AND v_version_minor >= 21 and v_version_minor < 23 THEN 439 | RETURN QUERY SELECT 440 | v_row.target_host AS pgbouncer_target_host 441 | , x."type" 442 | , x."user" 443 | , x.database 444 | , '' AS replication 445 | , x.state 446 | , x.addr 447 | , x.port 448 | , x.local_addr 449 | , x.local_port 450 | , x.connect_time 451 | , x.request_time 452 | , x.wait 453 | , x.wait_us 454 | , x.close_needed 455 | , x.ptr 456 | , x.link 457 | , x.remote_pid 458 | , x.tls 459 | , x.application_name 460 | , x.prepared_statements 461 | FROM dblink(v_row.target_host, 'show servers') AS x 462 | ( 463 | "type" text 464 | , "user" text 465 | , database text 466 | , state text 467 | , addr text 468 | , port int 469 | , local_addr text 470 | , local_port int 471 | , connect_time timestamp with time zone 472 | , request_time timestamp with time zone 473 | , wait int 474 | , wait_us int 475 | , close_needed int 476 | , ptr text 477 | , link text 478 | , remote_pid int 479 | , tls text 480 | , application_name text 481 | , prepared_statements int 482 | ); 483 | ELSIF v_version_major = 1 AND v_version_minor >= 18 and v_version_minor < 21 THEN 484 | RETURN QUERY SELECT 485 | v_row.target_host AS pgbouncer_target_host 486 | , x."type" 487 | , x."user" 488 | , x.database 489 | , '' AS replication 490 | , x.state 491 | , x.addr 492 | , x.port 493 | , x.local_addr 494 | , x.local_port 495 | , x.connect_time 496 | , x.request_time 497 | , x.wait 498 | , x.wait_us 499 | , x.close_needed 500 | , x.ptr 501 | , x.link 502 | , x.remote_pid 503 | , x.tls 504 | , x.application_name 505 | , 0 AS prepared_statements 506 | FROM dblink(v_row.target_host, 'show servers') AS x 507 | ( 508 | "type" text 509 | , "user" text 510 | , database text 511 | , state text 512 | , addr text 513 | , port int 514 | , local_addr text 515 | , local_port int 516 | , connect_time timestamp with time zone 517 | , request_time timestamp with time zone 518 | , wait int 519 | , wait_us int 520 | , close_needed int 521 | , ptr text 522 | , link text 523 | , remote_pid int 524 | , tls text 525 | , application_name text 526 | ); 527 | -- backward compatiblity floor is 1.17 528 | ELSIF v_version_major = 1 AND v_version_minor = 17 THEN 529 | RETURN QUERY SELECT 530 | v_row.target_host AS pgbouncer_target_host 531 | , x."type" 532 | , x."user" 533 | , x.database 534 | , '' AS replication 535 | , x.state 536 | , x.addr 537 | , x.port 538 | , x.local_addr 539 | , x.local_port 540 | , x.connect_time 541 | , x.request_time 542 | , x.wait 543 | , x.wait_us 544 | , x.close_needed 545 | , x.ptr 546 | , x.link 547 | , x.remote_pid 548 | , x.tls 549 | , '' AS application_name 550 | , 0 AS prepared_statements 551 | FROM dblink(v_row.target_host, 'show servers') AS x 552 | ( 553 | "type" text 554 | , "user" text 555 | , database text 556 | , state text 557 | , addr text 558 | , port int 559 | , local_addr text 560 | , local_port int 561 | , connect_time timestamp with time zone 562 | , request_time timestamp with time zone 563 | , wait int 564 | , wait_us int 565 | , close_needed int 566 | , ptr text 567 | , link text 568 | , remote_pid int 569 | , tls text 570 | ); 571 | ELSE 572 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 573 | END IF; 574 | EXCEPTION 575 | WHEN connection_exception THEN 576 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 577 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 578 | ex_context = PG_EXCEPTION_CONTEXT, 579 | ex_detail = PG_EXCEPTION_DETAIL, 580 | ex_hint = PG_EXCEPTION_HINT; 581 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 582 | ORIGINAL ERROR: % 583 | CONTEXT: % 584 | DETAIL: % 585 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 586 | END; 587 | END LOOP; 588 | 589 | END 590 | $$; 591 | 592 | 593 | CREATE FUNCTION @extschema@.pgbouncer_sockets_func() RETURNS TABLE 594 | ( 595 | pgbouncer_target_host text 596 | , "type" text 597 | , "user" text 598 | , database text 599 | , replication text 600 | , state text 601 | , addr text 602 | , port int 603 | , local_addr text 604 | , local_port int 605 | , connect_time timestamp with time zone 606 | , request_time timestamp with time zone 607 | , wait int 608 | , wait_us int 609 | , close_needed int 610 | , ptr text 611 | , link text 612 | , remote_pid int 613 | , tls text 614 | , application_name text 615 | , recv_pos int 616 | , pkt_pos int 617 | , pkt_remain int 618 | , send_pos int 619 | , send_remain int 620 | , pkt_avail int 621 | , send_avail int 622 | , prepared_statements int 623 | ) 624 | LANGUAGE plpgsql 625 | AS $$ 626 | DECLARE 627 | ex_context text; 628 | ex_detail text; 629 | ex_hint text; 630 | ex_message text; 631 | v_row record; 632 | v_version_major int; 633 | v_version_minor int; 634 | BEGIN 635 | 636 | FOR v_row IN 637 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 638 | LOOP BEGIN 639 | SELECT version_major, version_minor 640 | INTO v_version_major, v_version_minor 641 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 642 | 643 | IF v_version_major >= 1 AND v_version_minor >= 23 THEN 644 | RETURN QUERY SELECT 645 | v_row.target_host AS pgbouncer_target_host 646 | , x."type" 647 | , x."user" 648 | , x.database 649 | , x.replication 650 | , x.state 651 | , x.addr 652 | , x.port 653 | , x.local_addr 654 | , x.local_port 655 | , x.connect_time 656 | , x.request_time 657 | , x.wait 658 | , x.wait_us 659 | , x.close_needed 660 | , x.ptr 661 | , x.link 662 | , x.remote_pid 663 | , x.tls 664 | , x.application_name 665 | , x.recv_pos 666 | , x.pkt_pos 667 | , x.pkt_remain 668 | , x.send_pos 669 | , x.send_remain 670 | , x.pkt_avail 671 | , x.send_avail 672 | , x.prepared_statements 673 | FROM dblink(v_row.target_host, 'show sockets') AS x 674 | ( 675 | "type" text 676 | , "user" text 677 | , database text 678 | , replication text 679 | , state text 680 | , addr text 681 | , port int 682 | , local_addr text 683 | , local_port int 684 | , connect_time timestamp with time zone 685 | , request_time timestamp with time zone 686 | , wait int 687 | , wait_us int 688 | , close_needed int 689 | , ptr text 690 | , link text 691 | , remote_pid int 692 | , tls text 693 | , application_name text 694 | , recv_pos int 695 | , pkt_pos int 696 | , pkt_remain int 697 | , send_pos int 698 | , send_remain int 699 | , pkt_avail int 700 | , send_avail int 701 | , prepared_statements int 702 | ); 703 | ELSIF v_version_major = 1 AND v_version_minor >= 21 AND v_version_minor < 23 THEN 704 | RETURN QUERY SELECT 705 | v_row.target_host AS pgbouncer_target_host 706 | , x."type" 707 | , x."user" 708 | , x.database 709 | , '' AS replication 710 | , x.state 711 | , x.addr 712 | , x.port 713 | , x.local_addr 714 | , x.local_port 715 | , x.connect_time 716 | , x.request_time 717 | , x.wait 718 | , x.wait_us 719 | , x.close_needed 720 | , x.ptr 721 | , x.link 722 | , x.remote_pid 723 | , x.tls 724 | , x.application_name 725 | , x.recv_pos 726 | , x.pkt_pos 727 | , x.pkt_remain 728 | , x.send_pos 729 | , x.send_remain 730 | , x.pkt_avail 731 | , x.send_avail 732 | , x.prepared_statements 733 | FROM dblink(v_row.target_host, 'show sockets') AS x 734 | ( 735 | "type" text 736 | , "user" text 737 | , database text 738 | , state text 739 | , addr text 740 | , port int 741 | , local_addr text 742 | , local_port int 743 | , connect_time timestamp with time zone 744 | , request_time timestamp with time zone 745 | , wait int 746 | , wait_us int 747 | , close_needed int 748 | , ptr text 749 | , link text 750 | , remote_pid int 751 | , tls text 752 | , application_name text 753 | , recv_pos int 754 | , pkt_pos int 755 | , pkt_remain int 756 | , send_pos int 757 | , send_remain int 758 | , pkt_avail int 759 | , send_avail int 760 | , prepared_statements int 761 | ); 762 | ELSIF v_version_major = 1 AND v_version_minor >= 18 AND v_version_minor < 21 THEN 763 | RETURN QUERY SELECT 764 | v_row.target_host AS pgbouncer_target_host 765 | , x."type" 766 | , x."user" 767 | , x.database 768 | , '' AS replication 769 | , x.state 770 | , x.addr 771 | , x.port 772 | , x.local_addr 773 | , x.local_port 774 | , x.connect_time 775 | , x.request_time 776 | , x.wait 777 | , x.wait_us 778 | , x.close_needed 779 | , x.ptr 780 | , x.link 781 | , x.remote_pid 782 | , x.tls 783 | , x.application_name 784 | , x.recv_pos 785 | , x.pkt_pos 786 | , x.pkt_remain 787 | , x.send_pos 788 | , x.send_remain 789 | , x.pkt_avail 790 | , x.send_avail 791 | , 0 AS prepared_statements 792 | FROM dblink(v_row.target_host, 'show sockets') AS x 793 | ( 794 | "type" text 795 | , "user" text 796 | , database text 797 | , state text 798 | , addr text 799 | , port int 800 | , local_addr text 801 | , local_port int 802 | , connect_time timestamp with time zone 803 | , request_time timestamp with time zone 804 | , wait int 805 | , wait_us int 806 | , close_needed int 807 | , ptr text 808 | , link text 809 | , remote_pid int 810 | , tls text 811 | , application_name text 812 | , recv_pos int 813 | , pkt_pos int 814 | , pkt_remain int 815 | , send_pos int 816 | , send_remain int 817 | , pkt_avail int 818 | , send_avail int 819 | ); 820 | -- backward compatiblity floor is 1.17 821 | ELSIF v_version_major = 1 AND v_version_minor = 17 THEN 822 | RETURN QUERY SELECT 823 | v_row.target_host AS pgbouncer_target_host 824 | , x."type" 825 | , x."user" 826 | , x.database 827 | , '' AS replication 828 | , x.state 829 | , x.addr 830 | , x.port 831 | , x.local_addr 832 | , x.local_port 833 | , x.connect_time 834 | , x.request_time 835 | , x.wait 836 | , x.wait_us 837 | , x.close_needed 838 | , x.ptr 839 | , x.link 840 | , x.remote_pid 841 | , x.tls 842 | , '' AS application_name 843 | , x.recv_pos 844 | , x.pkt_pos 845 | , x.pkt_remain 846 | , x.send_pos 847 | , x.send_remain 848 | , x.pkt_avail 849 | , x.send_avail 850 | , 0 AS prepared_statements 851 | FROM dblink(v_row.target_host, 'show sockets') AS x 852 | ( 853 | "type" text 854 | , "user" text 855 | , database text 856 | , state text 857 | , addr text 858 | , port int 859 | , local_addr text 860 | , local_port int 861 | , connect_time timestamp with time zone 862 | , request_time timestamp with time zone 863 | , wait int 864 | , wait_us int 865 | , close_needed int 866 | , ptr text 867 | , link text 868 | , remote_pid int 869 | , tls text 870 | , recv_pos int 871 | , pkt_pos int 872 | , pkt_remain int 873 | , send_pos int 874 | , send_remain int 875 | , pkt_avail int 876 | , send_avail int 877 | ); 878 | ELSE 879 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 880 | END IF; 881 | EXCEPTION 882 | WHEN connection_exception THEN 883 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 884 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 885 | ex_context = PG_EXCEPTION_CONTEXT, 886 | ex_detail = PG_EXCEPTION_DETAIL, 887 | ex_hint = PG_EXCEPTION_HINT; 888 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 889 | ORIGINAL ERROR: % 890 | CONTEXT: % 891 | DETAIL: % 892 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 893 | END; 894 | END LOOP; 895 | 896 | END 897 | $$; 898 | 899 | 900 | CREATE FUNCTION @extschema@.pgbouncer_databases_func() RETURNS TABLE 901 | ( 902 | pgbouncer_target_host text 903 | , name text 904 | , host text 905 | , port int 906 | , database text 907 | , force_user text 908 | , pool_size int 909 | , min_pool_size int 910 | , reserve_pool int 911 | , server_lifetime int 912 | , pool_mode text 913 | , max_connections int 914 | , current_connections int 915 | , paused int 916 | , disabled int 917 | ) 918 | LANGUAGE plpgsql 919 | AS $$ 920 | DECLARE 921 | ex_context text; 922 | ex_detail text; 923 | ex_hint text; 924 | ex_message text; 925 | v_row record; 926 | v_version_major int; 927 | v_version_minor int; 928 | BEGIN 929 | 930 | FOR v_row IN 931 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 932 | LOOP BEGIN 933 | 934 | SELECT version_major, version_minor 935 | INTO v_version_major, v_version_minor 936 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 937 | 938 | IF v_version_major >= 1 AND v_version_minor >= 23 THEN 939 | RETURN QUERY SELECT 940 | v_row.target_host AS pgbouncer_target_host 941 | , x.name 942 | , x.host 943 | , x.port 944 | , x.database 945 | , x.force_user 946 | , x.pool_size 947 | , x.min_pool_size 948 | , x.reserve_pool 949 | , x.server_lifetime 950 | , x.pool_mode 951 | , x.max_connections 952 | , x.current_connections 953 | , x.paused 954 | , x.disabled 955 | FROM dblink(v_row.target_host, 'show databases') AS x 956 | ( 957 | name text 958 | , host text 959 | , port int 960 | , database text 961 | , force_user text 962 | , pool_size int 963 | , min_pool_size int 964 | , reserve_pool int 965 | , server_lifetime int 966 | , pool_mode text 967 | , max_connections int 968 | , current_connections int 969 | , paused int 970 | , disabled int 971 | ); 972 | ELSIF v_version_major = 1 AND v_version_minor < 23 THEN 973 | RETURN QUERY SELECT 974 | v_row.target_host AS pgbouncer_target_host 975 | , x.name 976 | , x.host 977 | , x.port 978 | , x.database 979 | , x.force_user 980 | , x.pool_size 981 | , x.min_pool_size 982 | , x.reserve_pool 983 | , 0 AS server_lifetime 984 | , x.pool_mode 985 | , x.max_connections 986 | , x.current_connections 987 | , x.paused 988 | , x.disabled 989 | FROM dblink(v_row.target_host, 'show databases') AS x 990 | ( 991 | name text 992 | , host text 993 | , port int 994 | , database text 995 | , force_user text 996 | , pool_size int 997 | , min_pool_size int 998 | , reserve_pool int 999 | , pool_mode text 1000 | , max_connections int 1001 | , current_connections int 1002 | , paused int 1003 | , disabled int 1004 | ); 1005 | ELSE 1006 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 1007 | END IF; 1008 | EXCEPTION 1009 | WHEN connection_exception THEN 1010 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 1011 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 1012 | ex_context = PG_EXCEPTION_CONTEXT, 1013 | ex_detail = PG_EXCEPTION_DETAIL, 1014 | ex_hint = PG_EXCEPTION_HINT; 1015 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 1016 | ORIGINAL ERROR: % 1017 | CONTEXT: % 1018 | DETAIL: % 1019 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 1020 | END; 1021 | END LOOP; 1022 | 1023 | END 1024 | $$; 1025 | 1026 | 1027 | CREATE FUNCTION @extschema@.pgbouncer_stats_func() RETURNS TABLE 1028 | ( 1029 | pgbouncer_target_host text 1030 | , database text 1031 | , total_server_assignment_count bigint 1032 | , total_xact_count bigint 1033 | , total_query_count bigint 1034 | , total_received bigint 1035 | , total_sent bigint 1036 | , total_xact_time bigint 1037 | , total_query_time bigint 1038 | , total_wait_time bigint 1039 | , avg_server_assignment_count bigint 1040 | , avg_xact_count bigint 1041 | , avg_query_count bigint 1042 | , avg_recv bigint 1043 | , avg_sent bigint 1044 | , avg_xact_time bigint 1045 | , avg_query_time bigint 1046 | , avg_wait_time bigint 1047 | ) 1048 | LANGUAGE plpgsql 1049 | AS $$ 1050 | DECLARE 1051 | ex_context text; 1052 | ex_detail text; 1053 | ex_hint text; 1054 | ex_message text; 1055 | v_row record; 1056 | v_version_major int; 1057 | v_version_minor int; 1058 | BEGIN 1059 | 1060 | FOR v_row IN 1061 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 1062 | LOOP BEGIN 1063 | 1064 | SELECT version_major, version_minor 1065 | INTO v_version_major, v_version_minor 1066 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 1067 | 1068 | IF v_version_major >= 1 AND v_version_minor >= 23 THEN 1069 | RETURN QUERY SELECT 1070 | v_row.target_host AS pgbouncer_target_host 1071 | , x.database 1072 | , x.total_server_assignment_count 1073 | , x.total_xact_count 1074 | , x.total_query_count 1075 | , x.total_received 1076 | , x.total_sent 1077 | , x.total_xact_time 1078 | , x.total_query_time 1079 | , x.total_wait_time 1080 | , x.avg_server_assignment_count 1081 | , x.avg_xact_count 1082 | , x.avg_query_count 1083 | , x.avg_recv 1084 | , x.avg_sent 1085 | , x.avg_xact_time 1086 | , x.avg_query_time 1087 | , x.avg_wait_time 1088 | FROM dblink(v_row.target_host, 'show stats') AS x 1089 | ( 1090 | database text 1091 | , total_server_assignment_count bigint 1092 | , total_xact_count bigint 1093 | , total_query_count bigint 1094 | , total_received bigint 1095 | , total_sent bigint 1096 | , total_xact_time bigint 1097 | , total_query_time bigint 1098 | , total_wait_time bigint 1099 | , avg_server_assignment_count bigint 1100 | , avg_xact_count bigint 1101 | , avg_query_count bigint 1102 | , avg_recv bigint 1103 | , avg_sent bigint 1104 | , avg_xact_time bigint 1105 | , avg_query_time bigint 1106 | , avg_wait_time bigint 1107 | ); 1108 | ELSIF v_version_major = 1 AND v_version_minor < 23 THEN 1109 | RETURN QUERY SELECT 1110 | v_row.target_host AS pgbouncer_target_host 1111 | , x.database 1112 | , 0 AS total_server_assignment_count 1113 | , x.total_xact_count 1114 | , x.total_query_count 1115 | , x.total_received 1116 | , x.total_sent 1117 | , x.total_xact_time 1118 | , x.total_query_time 1119 | , x.total_wait_time 1120 | , 0 AS avg_server_assignment_count 1121 | , x.avg_xact_count 1122 | , x.avg_query_count 1123 | , x.avg_recv 1124 | , x.avg_sent 1125 | , x.avg_xact_time 1126 | , x.avg_query_time 1127 | , x.avg_wait_time 1128 | FROM dblink(v_row.target_host, 'show stats') AS x 1129 | ( 1130 | database text 1131 | , total_xact_count bigint 1132 | , total_query_count bigint 1133 | , total_received bigint 1134 | , total_sent bigint 1135 | , total_xact_time bigint 1136 | , total_query_time bigint 1137 | , total_wait_time bigint 1138 | , avg_xact_count bigint 1139 | , avg_query_count bigint 1140 | , avg_recv bigint 1141 | , avg_sent bigint 1142 | , avg_xact_time bigint 1143 | , avg_query_time bigint 1144 | , avg_wait_time bigint 1145 | ); 1146 | ELSE 1147 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 1148 | END IF; 1149 | EXCEPTION 1150 | WHEN connection_exception THEN 1151 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 1152 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 1153 | ex_context = PG_EXCEPTION_CONTEXT, 1154 | ex_detail = PG_EXCEPTION_DETAIL, 1155 | ex_hint = PG_EXCEPTION_HINT; 1156 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 1157 | ORIGINAL ERROR: % 1158 | CONTEXT: % 1159 | DETAIL: % 1160 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 1161 | END; 1162 | END LOOP; 1163 | 1164 | END 1165 | $$; 1166 | 1167 | 1168 | CREATE FUNCTION @extschema@.pgbouncer_users_func() RETURNS TABLE 1169 | ( 1170 | pgbouncer_target_host text 1171 | , name text 1172 | , pool_size text 1173 | , pool_mode text 1174 | , max_user_connections int 1175 | , current_connections int 1176 | ) 1177 | LANGUAGE plpgsql 1178 | AS $$ 1179 | DECLARE 1180 | ex_context text; 1181 | ex_detail text; 1182 | ex_hint text; 1183 | ex_message text; 1184 | v_row record; 1185 | v_version_major int; 1186 | v_version_minor int; 1187 | BEGIN 1188 | 1189 | FOR v_row IN 1190 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 1191 | LOOP BEGIN 1192 | 1193 | SELECT version_major, version_minor 1194 | INTO v_version_major, v_version_minor 1195 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 1196 | 1197 | IF v_version_major >= 1 AND v_version_minor >= 23 THEN 1198 | RETURN QUERY SELECT 1199 | v_row.target_host AS pgbouncer_target_host 1200 | , x.name 1201 | , x.pool_size 1202 | , x.pool_mode 1203 | , x.max_user_connections 1204 | , x.current_connections 1205 | FROM dblink(v_row.target_host, 'show users') AS x 1206 | ( 1207 | name text 1208 | , pool_size text 1209 | , pool_mode text 1210 | , max_user_connections int 1211 | , current_connections int 1212 | ); 1213 | ELSIF v_version_major = 1 AND v_version_minor < 23 THEN 1214 | RETURN QUERY SELECT 1215 | v_row.target_host AS pgbouncer_target_host 1216 | , x.name 1217 | , 0 AS pool_size 1218 | , x.pool_mode 1219 | , 0 AS max_user_connections 1220 | , 0 AS current_connections 1221 | FROM dblink(v_row.target_host, 'show users') AS x 1222 | ( 1223 | name text 1224 | , pool_mode text 1225 | ); 1226 | ELSE 1227 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 1228 | END IF; 1229 | EXCEPTION 1230 | WHEN connection_exception THEN 1231 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 1232 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 1233 | ex_context = PG_EXCEPTION_CONTEXT, 1234 | ex_detail = PG_EXCEPTION_DETAIL, 1235 | ex_hint = PG_EXCEPTION_HINT; 1236 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 1237 | ORIGINAL ERROR: % 1238 | CONTEXT: % 1239 | DETAIL: % 1240 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 1241 | END; 1242 | END LOOP; 1243 | END 1244 | $$; 1245 | 1246 | 1247 | CREATE VIEW @extschema@.pgbouncer_clients AS 1248 | SELECT pgbouncer_target_host 1249 | , "type" 1250 | , "user" 1251 | , database 1252 | , replication 1253 | , state 1254 | , addr 1255 | , port 1256 | , local_addr 1257 | , local_port 1258 | , connect_time 1259 | , request_time 1260 | , wait 1261 | , wait_us 1262 | , close_needed 1263 | , ptr 1264 | , link 1265 | , remote_pid 1266 | , tls 1267 | , application_name 1268 | , prepared_statements 1269 | FROM @extschema@.pgbouncer_clients_func(); 1270 | 1271 | 1272 | CREATE VIEW @extschema@.pgbouncer_servers AS 1273 | SELECT pgbouncer_target_host 1274 | , "type" 1275 | , "user" 1276 | , database 1277 | , replication 1278 | , state 1279 | , addr 1280 | , port 1281 | , local_addr 1282 | , local_port 1283 | , connect_time 1284 | , request_time 1285 | , wait 1286 | , wait_us 1287 | , close_needed 1288 | , ptr 1289 | , link 1290 | , remote_pid 1291 | , tls 1292 | , application_name 1293 | , prepared_statements 1294 | FROM @extschema@.pgbouncer_servers_func(); 1295 | 1296 | 1297 | CREATE VIEW @extschema@.pgbouncer_sockets AS 1298 | SELECT pgbouncer_target_host 1299 | , "type" 1300 | , "user" 1301 | , database 1302 | , replication 1303 | , state 1304 | , addr 1305 | , port 1306 | , local_addr 1307 | , local_port 1308 | , connect_time 1309 | , request_time 1310 | , wait 1311 | , wait_us 1312 | , close_needed 1313 | , ptr 1314 | , link 1315 | , remote_pid 1316 | , tls 1317 | , application_name 1318 | , recv_pos 1319 | , pkt_pos 1320 | , pkt_remain 1321 | , send_pos 1322 | , send_remain 1323 | , pkt_avail 1324 | , send_avail 1325 | , prepared_statements 1326 | FROM @extschema@.pgbouncer_sockets_func(); 1327 | 1328 | 1329 | CREATE VIEW @extschema@.pgbouncer_databases AS 1330 | SELECT pgbouncer_target_host 1331 | , name 1332 | , host 1333 | , port 1334 | , database 1335 | , force_user 1336 | , pool_size 1337 | , min_pool_size 1338 | , reserve_pool 1339 | , server_lifetime 1340 | , pool_mode 1341 | , max_connections 1342 | , current_connections 1343 | , paused 1344 | , disabled 1345 | FROM @extschema@.pgbouncer_databases_func(); 1346 | 1347 | 1348 | CREATE VIEW @extschema@.pgbouncer_stats AS 1349 | SELECT pgbouncer_target_host 1350 | , database 1351 | , total_server_assignment_count 1352 | , total_xact_count 1353 | , total_query_count 1354 | , total_received 1355 | , total_sent 1356 | , total_xact_time 1357 | , total_query_time 1358 | , total_wait_time 1359 | , avg_server_assignment_count 1360 | , avg_xact_count 1361 | , avg_query_count 1362 | , avg_recv 1363 | , avg_sent 1364 | , avg_xact_time 1365 | , avg_query_time 1366 | , avg_wait_time 1367 | FROM @extschema@.pgbouncer_stats_func(); 1368 | 1369 | 1370 | CREATE VIEW @extschema@.pgbouncer_users AS 1371 | SELECT pgbouncer_target_host 1372 | , name 1373 | , pool_size 1374 | , pool_mode 1375 | , max_user_connections 1376 | , current_connections 1377 | FROM @extschema@.pgbouncer_users_func(); 1378 | 1379 | 1380 | -- Restore dropped object privileges 1381 | DO $$ 1382 | DECLARE 1383 | v_row record; 1384 | BEGIN 1385 | FOR v_row IN SELECT statement FROM pgbouncer_fdw_preserve_privs_temp LOOP 1386 | IF v_row.statement IS NOT NULL THEN 1387 | EXECUTE v_row.statement; 1388 | END IF; 1389 | END LOOP; 1390 | END 1391 | $$; 1392 | 1393 | DROP TABLE IF EXISTS pgbouncer_fdw_preserve_privs_temp; 1394 | -------------------------------------------------------------------------------- /updates/pgbouncer_fdw--0.5--1.0.0.sql: -------------------------------------------------------------------------------- 1 | -- IMPORTANT NOTE: All objects in this extension are dropped and recreated as part of this update. Privileges ARE NOT preserved as part of this update, so please ensure privileges you have on these objects are preserved before upgrading so that they can be reapplied. Note that execution by PUBLIC on the admin functions is once again revoked by this update. 2 | 3 | -- Add support for gathering statistics from multiple pgBouncer targets 4 | -- A new configuration table has been added to define the names of all FDW servers. 5 | -- All administrative command functions have had a parameter for the FDW server name added to them. These functions intentionally do not use the configuration table to avoid accidentally running an admin command on multiple servers. 6 | 7 | -- Add better support for multiple versions of pgBouncer. Support for 1.17 has been backported into this version of pgbouncer_fdw. 8 | 9 | DROP VIEW @extschema@.pgbouncer_clients; 10 | DROP VIEW @extschema@.pgbouncer_config; 11 | DROP VIEW @extschema@.pgbouncer_databases; 12 | DROP VIEW @extschema@.pgbouncer_dns_hosts; 13 | DROP VIEW @extschema@.pgbouncer_dns_zones; 14 | DROP VIEW @extschema@.pgbouncer_lists; 15 | DROP VIEW @extschema@.pgbouncer_pools; 16 | DROP VIEW @extschema@.pgbouncer_servers; 17 | DROP VIEW @extschema@.pgbouncer_sockets; 18 | DROP VIEW @extschema@.pgbouncer_stats; 19 | DROP VIEW @extschema@.pgbouncer_users; 20 | 21 | DROP FUNCTION @extschema@.pgbouncer_command_disable(text); 22 | DROP FUNCTION @extschema@.pgbouncer_command_enable(text); 23 | DROP FUNCTION @extschema@.pgbouncer_command_kill(text); 24 | DROP FUNCTION @extschema@.pgbouncer_command_pause(text); 25 | DROP FUNCTION @extschema@.pgbouncer_command_reconnect(text); 26 | DROP FUNCTION @extschema@.pgbouncer_command_reload(); 27 | DROP FUNCTION @extschema@.pgbouncer_command_resume(text); 28 | DROP FUNCTION @extschema@.pgbouncer_command_set(text, text); 29 | DROP FUNCTION @extschema@.pgbouncer_command_shutdown(); 30 | DROP FUNCTION @extschema@.pgbouncer_command_suspend(); 31 | DROP FUNCTION @extschema@.pgbouncer_command_wait_close(text); 32 | 33 | /* 34 | * pgbouncer_fdw_targets 35 | */ 36 | CREATE TABLE @extschema@.pgbouncer_fdw_targets ( 37 | target_host text NOT NULL 38 | , active boolean NOT NULL DEFAULT true 39 | , CONSTRAINT pgbouncer_fdw_targets_pk PRIMARY KEY (target_host) ); 40 | CREATE INDEX pgbouncer_fdw_targets_active_idx ON pgbouncer_fdw_targets (active); 41 | SELECT pg_catalog.pg_extension_config_dump('pgbouncer_fdw_targets', ''); 42 | 43 | INSERT INTO @extschema@.pgbouncer_fdw_targets ( target_host ) VALUES ('pgbouncer'); 44 | 45 | 46 | /* 47 | * pgbouncer_version_func 48 | */ 49 | CREATE FUNCTION @extschema@.pgbouncer_version_func(p_target_host text DEFAULT NULL) RETURNS TABLE 50 | ( 51 | pgbouncer_target_host text 52 | , version_major int 53 | , version_minor int 54 | , version_patch int 55 | ) 56 | LANGUAGE plpgsql 57 | AS $$ 58 | DECLARE 59 | ex_context text; 60 | ex_detail text; 61 | ex_hint text; 62 | ex_message text; 63 | v_row record; 64 | v_sql text; 65 | BEGIN 66 | 67 | v_sql := 'SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active'; 68 | IF p_target_host IS NOT NULL THEN 69 | v_sql := v_sql || format(' AND target_host = %L', p_target_host); 70 | END IF; 71 | 72 | FOR v_row IN EXECUTE v_sql 73 | LOOP BEGIN 74 | RETURN QUERY SELECT 75 | v_row.target_host AS pgbouncer_target_host 76 | , split_part(substring(version from '\d.+'), '.', 1)::int AS version_major 77 | , split_part(substring(version from '\d.+'), '.', 2)::int AS version_minor 78 | , split_part(substring(version from '\d.+'), '.', 3)::int AS version_patch 79 | FROM dblink(v_row.target_host, 'show version') AS x 80 | ( 81 | version text 82 | ); 83 | EXCEPTION 84 | WHEN connection_exception THEN 85 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 86 | ex_context = PG_EXCEPTION_CONTEXT, 87 | ex_detail = PG_EXCEPTION_DETAIL, 88 | ex_hint = PG_EXCEPTION_HINT; 89 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 90 | ORIGINAL ERROR: % 91 | CONTEXT: % 92 | DETAIL: % 93 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 94 | END; 95 | END LOOP; 96 | END 97 | $$; 98 | 99 | CREATE VIEW @extschema@.pgbouncer_version AS 100 | SELECT pgbouncer_target_host 101 | , version_major 102 | , version_minor 103 | , version_patch 104 | FROM @extschema@.pgbouncer_version_func(); 105 | 106 | 107 | /* 108 | * pgbouncer_clients_func 109 | */ 110 | CREATE FUNCTION @extschema@.pgbouncer_clients_func() RETURNS TABLE 111 | ( 112 | pgbouncer_target_host text 113 | , "type" text 114 | , "user" text 115 | , database text 116 | , state text 117 | , addr text 118 | , port int 119 | , local_addr text 120 | , local_port int 121 | , connect_time timestamp with time zone 122 | , request_time timestamp with time zone 123 | , wait int 124 | , wait_us int 125 | , close_needed int 126 | , ptr text 127 | , link text 128 | , remote_pid int 129 | , tls text 130 | , application_name text 131 | ) 132 | LANGUAGE plpgsql 133 | AS $$ 134 | DECLARE 135 | ex_context text; 136 | ex_detail text; 137 | ex_hint text; 138 | ex_message text; 139 | v_row record; 140 | v_version_major int; 141 | v_version_minor int; 142 | BEGIN 143 | 144 | FOR v_row IN 145 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 146 | LOOP BEGIN 147 | 148 | SELECT version_major, version_minor 149 | INTO v_version_major, v_version_minor 150 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 151 | 152 | IF v_version_major >= 1 AND v_version_minor >= 18 THEN 153 | RETURN QUERY SELECT 154 | v_row.target_host AS pgbouncer_target_host 155 | , x."type" 156 | , x."user" 157 | , x.database 158 | , x.state 159 | , x.addr 160 | , x.port 161 | , x.local_addr 162 | , x.local_port 163 | , x.connect_time 164 | , x.request_time 165 | , x.wait 166 | , x.wait_us 167 | , x.close_needed 168 | , x.ptr 169 | , x.link 170 | , x.remote_pid 171 | , x.tls 172 | , x.application_name 173 | FROM dblink(v_row.target_host, 'show clients') AS x 174 | ( "type" text 175 | , "user" text 176 | , database text 177 | , state text 178 | , addr text 179 | , port int 180 | , local_addr text 181 | , local_port int 182 | , connect_time timestamp with time zone 183 | , request_time timestamp with time zone 184 | , wait int 185 | , wait_us int 186 | , close_needed int 187 | , ptr text 188 | , link text 189 | , remote_pid int 190 | , tls text 191 | , application_name text 192 | ); 193 | -- backward compatiblity floor is 1.17 194 | ELSIF v_version_major = 1 AND v_version_minor = 17 THEN 195 | RETURN QUERY SELECT 196 | v_row.target_host AS pgbouncer_target_host 197 | , x."type" 198 | , x."user" 199 | , x.database 200 | , x.state 201 | , x.addr 202 | , x.port 203 | , x.local_addr 204 | , x.local_port 205 | , x.connect_time 206 | , x.request_time 207 | , x.wait 208 | , x.wait_us 209 | , x.close_needed 210 | , x.ptr 211 | , x.link 212 | , x.remote_pid 213 | , x.tls 214 | , '' AS application_name 215 | FROM dblink(v_row.target_host, 'show clients') AS x 216 | ( "type" text 217 | , "user" text 218 | , database text 219 | , state text 220 | , addr text 221 | , port int 222 | , local_addr text 223 | , local_port int 224 | , connect_time timestamp with time zone 225 | , request_time timestamp with time zone 226 | , wait int 227 | , wait_us int 228 | , close_needed int 229 | , ptr text 230 | , link text 231 | , remote_pid int 232 | , tls text 233 | ); 234 | ELSE 235 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 236 | END IF; 237 | EXCEPTION 238 | WHEN connection_exception THEN 239 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 240 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 241 | ex_context = PG_EXCEPTION_CONTEXT, 242 | ex_detail = PG_EXCEPTION_DETAIL, 243 | ex_hint = PG_EXCEPTION_HINT; 244 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 245 | ORIGINAL ERROR: % 246 | CONTEXT: % 247 | DETAIL: % 248 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 249 | END; 250 | END LOOP; 251 | 252 | END 253 | $$; 254 | 255 | CREATE VIEW @extschema@.pgbouncer_clients AS 256 | SELECT pgbouncer_target_host 257 | , "type" 258 | , "user" 259 | , database 260 | , state 261 | , addr 262 | , port 263 | , local_addr 264 | , local_port 265 | , connect_time 266 | , request_time 267 | , wait 268 | , wait_us 269 | , close_needed 270 | , ptr 271 | , link 272 | , remote_pid 273 | , tls 274 | , application_name 275 | FROM @extschema@.pgbouncer_clients_func(); 276 | 277 | 278 | /* 279 | * pgbouncer_config_func 280 | */ 281 | CREATE FUNCTION @extschema@.pgbouncer_config_func() RETURNS TABLE 282 | ( 283 | pgbouncer_target_host text 284 | , key text 285 | , value text 286 | , "default" text 287 | , changeable boolean 288 | ) 289 | LANGUAGE plpgsql 290 | AS $$ 291 | DECLARE 292 | ex_context text; 293 | ex_detail text; 294 | ex_hint text; 295 | ex_message text; 296 | v_row record; 297 | BEGIN 298 | 299 | FOR v_row IN 300 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 301 | LOOP BEGIN 302 | 303 | RETURN QUERY SELECT 304 | v_row.target_host AS pgbouncer_target_host 305 | , x.key 306 | , x.value 307 | , x."default" 308 | , x.changeable 309 | FROM dblink(v_row.target_host, 'show config') AS x 310 | ( key text 311 | , value text 312 | , "default" text 313 | , changeable boolean 314 | ); 315 | EXCEPTION 316 | WHEN connection_exception THEN 317 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 318 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 319 | ex_context = PG_EXCEPTION_CONTEXT, 320 | ex_detail = PG_EXCEPTION_DETAIL, 321 | ex_hint = PG_EXCEPTION_HINT; 322 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 323 | ORIGINAL ERROR: % 324 | CONTEXT: % 325 | DETAIL: % 326 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 327 | END; 328 | END LOOP; 329 | 330 | END 331 | $$; 332 | 333 | CREATE VIEW @extschema@.pgbouncer_config AS 334 | SELECT pgbouncer_target_host 335 | , key 336 | , value 337 | , "default" 338 | , changeable 339 | FROM @extschema@.pgbouncer_config_func(); 340 | 341 | 342 | /* 343 | * pgbouncer_databases_func 344 | */ 345 | CREATE FUNCTION @extschema@.pgbouncer_databases_func() RETURNS TABLE 346 | ( 347 | pgbouncer_target_host text 348 | , name text 349 | , host text 350 | , port int 351 | , database text 352 | , force_user text 353 | , pool_size int 354 | , min_pool_size int 355 | , reserve_pool int 356 | , pool_mode text 357 | , max_connections int 358 | , current_connections int 359 | , paused int 360 | , disabled int 361 | ) 362 | LANGUAGE plpgsql 363 | AS $$ 364 | DECLARE 365 | ex_context text; 366 | ex_detail text; 367 | ex_hint text; 368 | ex_message text; 369 | v_row record; 370 | BEGIN 371 | 372 | FOR v_row IN 373 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 374 | LOOP BEGIN 375 | 376 | RETURN QUERY SELECT 377 | v_row.target_host AS pgbouncer_target_host 378 | , x.name 379 | , x.host 380 | , x.port 381 | , x.database 382 | , x.force_user 383 | , x.pool_size 384 | , x.min_pool_size 385 | , x.reserve_pool 386 | , x.pool_mode 387 | , x.max_connections 388 | , x.current_connections 389 | , x.paused 390 | , x.disabled 391 | FROM dblink(v_row.target_host, 'show databases') AS x 392 | ( 393 | name text 394 | , host text 395 | , port int 396 | , database text 397 | , force_user text 398 | , pool_size int 399 | , min_pool_size int 400 | , reserve_pool int 401 | , pool_mode text 402 | , max_connections int 403 | , current_connections int 404 | , paused int 405 | , disabled int 406 | ); 407 | EXCEPTION 408 | WHEN connection_exception THEN 409 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 410 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 411 | ex_context = PG_EXCEPTION_CONTEXT, 412 | ex_detail = PG_EXCEPTION_DETAIL, 413 | ex_hint = PG_EXCEPTION_HINT; 414 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 415 | ORIGINAL ERROR: % 416 | CONTEXT: % 417 | DETAIL: % 418 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 419 | END; 420 | END LOOP; 421 | 422 | END 423 | $$; 424 | 425 | CREATE VIEW @extschema@.pgbouncer_databases AS 426 | SELECT pgbouncer_target_host 427 | , name 428 | , host 429 | , port 430 | , database 431 | , force_user 432 | , pool_size 433 | , min_pool_size 434 | , reserve_pool 435 | , pool_mode 436 | , max_connections 437 | , current_connections 438 | , paused 439 | , disabled 440 | FROM @extschema@.pgbouncer_databases_func(); 441 | 442 | 443 | /* 444 | * pgbouncer_dns_hosts_func 445 | */ 446 | CREATE FUNCTION @extschema@.pgbouncer_dns_hosts_func() RETURNS TABLE 447 | ( 448 | pgbouncer_target_host text 449 | , hostname text 450 | , ttl bigint 451 | , addrs text 452 | ) 453 | LANGUAGE plpgsql 454 | AS $$ 455 | DECLARE 456 | ex_context text; 457 | ex_detail text; 458 | ex_hint text; 459 | ex_message text; 460 | v_row record; 461 | BEGIN 462 | 463 | FOR v_row IN 464 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 465 | LOOP BEGIN 466 | 467 | RETURN QUERY SELECT 468 | v_row.target_host AS pgbouncer_target_host 469 | , x.hostname 470 | , x.ttl 471 | , x.addrs 472 | FROM dblink(v_row.target_host, 'show dns_hosts') AS x 473 | ( 474 | hostname text 475 | , ttl bigint 476 | , addrs text 477 | ); 478 | EXCEPTION 479 | WHEN connection_exception THEN 480 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 481 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 482 | ex_context = PG_EXCEPTION_CONTEXT, 483 | ex_detail = PG_EXCEPTION_DETAIL, 484 | ex_hint = PG_EXCEPTION_HINT; 485 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 486 | ORIGINAL ERROR: % 487 | CONTEXT: % 488 | DETAIL: % 489 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 490 | END; 491 | END LOOP; 492 | 493 | END 494 | $$; 495 | 496 | CREATE VIEW @extschema@.pgbouncer_dns_hosts AS 497 | SELECT pgbouncer_target_host 498 | , hostname 499 | , ttl 500 | , addrs 501 | FROM @extschema@.pgbouncer_dns_hosts_func(); 502 | 503 | /* 504 | * pgbouncer_dns_zones_func 505 | */ 506 | CREATE FUNCTION @extschema@.pgbouncer_dns_zones_func() RETURNS TABLE 507 | ( 508 | pgbouncer_target_host text 509 | , zonename text 510 | , serial text 511 | , count int 512 | ) 513 | LANGUAGE plpgsql 514 | AS $$ 515 | DECLARE 516 | ex_context text; 517 | ex_detail text; 518 | ex_hint text; 519 | ex_message text; 520 | v_row record; 521 | BEGIN 522 | 523 | FOR v_row IN 524 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 525 | LOOP BEGIN 526 | 527 | RETURN QUERY SELECT 528 | v_row.target_host AS pgbouncer_target_host 529 | , x.zonename 530 | , x.serial 531 | , x.count 532 | FROM dblink(v_row.target_host, 'show dns_zones') AS x 533 | ( 534 | zonename text 535 | , serial text 536 | , count int 537 | ); 538 | EXCEPTION 539 | WHEN connection_exception THEN 540 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 541 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 542 | ex_context = PG_EXCEPTION_CONTEXT, 543 | ex_detail = PG_EXCEPTION_DETAIL, 544 | ex_hint = PG_EXCEPTION_HINT; 545 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 546 | ORIGINAL ERROR: % 547 | CONTEXT: % 548 | DETAIL: % 549 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 550 | END; 551 | END LOOP; 552 | 553 | END 554 | $$; 555 | 556 | CREATE VIEW @extschema@.pgbouncer_dns_zones AS 557 | SELECT pgbouncer_target_host 558 | zonename 559 | , serial 560 | , count 561 | FROM @extschema@.pgbouncer_dns_zones_func(); 562 | 563 | 564 | /* 565 | * pgbouncer_lists_func 566 | */ 567 | CREATE FUNCTION @extschema@.pgbouncer_lists_func() RETURNS TABLE 568 | ( 569 | pgbouncer_target_host text 570 | , list text 571 | , items int 572 | ) 573 | LANGUAGE plpgsql 574 | AS $$ 575 | DECLARE 576 | ex_context text; 577 | ex_detail text; 578 | ex_hint text; 579 | ex_message text; 580 | v_row record; 581 | BEGIN 582 | 583 | FOR v_row IN 584 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 585 | LOOP BEGIN 586 | 587 | RETURN QUERY SELECT 588 | v_row.target_host AS pgbouncer_target_host 589 | , x.list 590 | , x.items 591 | FROM dblink(v_row.target_host, 'show lists') AS x 592 | ( 593 | list text 594 | , items int 595 | ); 596 | EXCEPTION 597 | WHEN connection_exception THEN 598 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 599 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 600 | ex_context = PG_EXCEPTION_CONTEXT, 601 | ex_detail = PG_EXCEPTION_DETAIL, 602 | ex_hint = PG_EXCEPTION_HINT; 603 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 604 | ORIGINAL ERROR: % 605 | CONTEXT: % 606 | DETAIL: % 607 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 608 | END; 609 | END LOOP; 610 | 611 | END 612 | $$; 613 | 614 | CREATE VIEW @extschema@.pgbouncer_lists AS 615 | SELECT pgbouncer_target_host 616 | , list 617 | , items 618 | FROM @extschema@.pgbouncer_lists_func(); 619 | 620 | 621 | /* 622 | * pgbouncer_pools_func 623 | */ 624 | CREATE FUNCTION @extschema@.pgbouncer_pools_func() RETURNS TABLE 625 | ( 626 | pgbouncer_target_host text 627 | , database text 628 | , "user" text 629 | , cl_active int 630 | , cl_waiting int 631 | , cl_active_cancel_req int 632 | , cl_waiting_cancel_req int 633 | , sv_active int 634 | , sv_active_cancel int 635 | , sv_being_canceled int 636 | , sv_idle int 637 | , sv_used int 638 | , sv_tested int 639 | , sv_login int 640 | , maxwait int 641 | , maxwait_us int 642 | , pool_mode text 643 | ) 644 | LANGUAGE plpgsql 645 | AS $$ 646 | DECLARE 647 | ex_context text; 648 | ex_detail text; 649 | ex_hint text; 650 | ex_message text; 651 | v_row record; 652 | v_version_major int; 653 | v_version_minor int; 654 | BEGIN 655 | 656 | FOR v_row IN 657 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 658 | LOOP BEGIN 659 | 660 | SELECT version_major, version_minor 661 | INTO v_version_major, v_version_minor 662 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 663 | 664 | IF v_version_major >= 1 AND v_version_minor >= 18 THEN 665 | RETURN QUERY SELECT 666 | v_row.target_host AS pgbouncer_target_host 667 | , x.database 668 | , x."user" 669 | , x.cl_active 670 | , x.cl_waiting 671 | , x.cl_active_cancel_req 672 | , x.cl_waiting_cancel_req 673 | , x.sv_active 674 | , x.sv_active_cancel 675 | , x.sv_being_canceled 676 | , x.sv_idle 677 | , x.sv_used 678 | , x.sv_tested 679 | , x.sv_login 680 | , x.maxwait 681 | , x.maxwait_us 682 | , x.pool_mode 683 | FROM dblink(v_row.target_host, 'show pools') AS x 684 | ( database text 685 | , "user" text 686 | , cl_active int 687 | , cl_waiting int 688 | , cl_active_cancel_req int 689 | , cl_waiting_cancel_req int 690 | , sv_active int 691 | , sv_active_cancel int 692 | , sv_being_canceled int 693 | , sv_idle int 694 | , sv_used int 695 | , sv_tested int 696 | , sv_login int 697 | , maxwait int 698 | , maxwait_us int 699 | , pool_mode text 700 | ); 701 | -- backward compatiblity floor is 1.17 702 | -- old cl_cancel_req is sent as cl_waiting_cancel_req 703 | ELSIF v_version_major = 1 AND v_version_minor = 17 THEN 704 | RETURN QUERY SELECT 705 | v_row.target_host AS pgbouncer_target_host 706 | , x.database 707 | , x."user" 708 | , x.cl_active 709 | , x.cl_waiting 710 | , 0 AS cl_active_cancel_req 711 | , x.cl_cancel_req AS cl_waiting_cancel_req 712 | , x.sv_active 713 | , 0 AS sv_active_cancel 714 | , 0 AS sv_being_canceled 715 | , x.sv_idle 716 | , x.sv_used 717 | , x.sv_tested 718 | , x.sv_login 719 | , x.maxwait 720 | , x.maxwait_us 721 | , x.pool_mode 722 | FROM dblink(v_row.target_host, 'show pools') AS x 723 | ( database text 724 | , "user" text 725 | , cl_active int 726 | , cl_waiting int 727 | , cl_cancel_req int 728 | , sv_active int 729 | , sv_idle int 730 | , sv_used int 731 | , sv_tested int 732 | , sv_login int 733 | , maxwait int 734 | , maxwait_us int 735 | , pool_mode text 736 | ); 737 | ELSE 738 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 739 | END IF; 740 | EXCEPTION 741 | WHEN connection_exception THEN 742 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 743 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 744 | ex_context = PG_EXCEPTION_CONTEXT, 745 | ex_detail = PG_EXCEPTION_DETAIL, 746 | ex_hint = PG_EXCEPTION_HINT; 747 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 748 | ORIGINAL ERROR: % 749 | CONTEXT: % 750 | DETAIL: % 751 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 752 | END; 753 | END LOOP; 754 | 755 | END 756 | $$; 757 | 758 | CREATE VIEW @extschema@.pgbouncer_pools AS 759 | SELECT pgbouncer_target_host 760 | , database 761 | , "user" 762 | , cl_active 763 | , cl_waiting 764 | , cl_active_cancel_req 765 | , cl_waiting_cancel_req 766 | , sv_active 767 | , sv_active_cancel 768 | , sv_being_canceled 769 | , sv_idle 770 | , sv_used 771 | , sv_tested 772 | , sv_login 773 | , maxwait 774 | , maxwait_us 775 | , pool_mode 776 | FROM @extschema@.pgbouncer_pools_func(); 777 | 778 | 779 | /* 780 | * pgbouncer_servers_func 781 | */ 782 | CREATE FUNCTION @extschema@.pgbouncer_servers_func() RETURNS TABLE 783 | ( 784 | pgbouncer_target_host text 785 | , "type" text 786 | , "user" text 787 | , database text 788 | , state text 789 | , addr text 790 | , port int 791 | , local_addr text 792 | , local_port int 793 | , connect_time timestamp with time zone 794 | , request_time timestamp with time zone 795 | , wait int 796 | , wait_us int 797 | , close_needed int 798 | , ptr text 799 | , link text 800 | , remote_pid int 801 | , tls text 802 | , application_name text 803 | ) 804 | LANGUAGE plpgsql 805 | AS $$ 806 | DECLARE 807 | ex_context text; 808 | ex_detail text; 809 | ex_hint text; 810 | ex_message text; 811 | v_row record; 812 | v_version_major int; 813 | v_version_minor int; 814 | BEGIN 815 | 816 | FOR v_row IN 817 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 818 | LOOP BEGIN 819 | 820 | SELECT version_major, version_minor 821 | INTO v_version_major, v_version_minor 822 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 823 | 824 | IF v_version_major >= 1 AND v_version_minor >= 18 THEN 825 | RETURN QUERY SELECT 826 | v_row.target_host AS pgbouncer_target_host 827 | , x."type" 828 | , x."user" 829 | , x.database 830 | , x.state 831 | , x.addr 832 | , x.port 833 | , x.local_addr 834 | , x.local_port 835 | , x.connect_time 836 | , x.request_time 837 | , x.wait 838 | , x.wait_us 839 | , x.close_needed 840 | , x.ptr 841 | , x.link 842 | , x.remote_pid 843 | , x.tls 844 | , x.application_name 845 | FROM dblink(v_row.target_host, 'show servers') AS x 846 | ( 847 | "type" text 848 | , "user" text 849 | , database text 850 | , state text 851 | , addr text 852 | , port int 853 | , local_addr text 854 | , local_port int 855 | , connect_time timestamp with time zone 856 | , request_time timestamp with time zone 857 | , wait int 858 | , wait_us int 859 | , close_needed int 860 | , ptr text 861 | , link text 862 | , remote_pid int 863 | , tls text 864 | , application_name text 865 | ); 866 | -- backward compatiblity floor is 1.17 867 | ELSIF v_version_major = 1 AND v_version_minor = 17 THEN 868 | RETURN QUERY SELECT 869 | v_row.target_host AS pgbouncer_target_host 870 | , x."type" 871 | , x."user" 872 | , x.database 873 | , x.state 874 | , x.addr 875 | , x.port 876 | , x.local_addr 877 | , x.local_port 878 | , x.connect_time 879 | , x.request_time 880 | , x.wait 881 | , x.wait_us 882 | , x.close_needed 883 | , x.ptr 884 | , x.link 885 | , x.remote_pid 886 | , x.tls 887 | , '' AS application_name 888 | FROM dblink(v_row.target_host, 'show servers') AS x 889 | ( 890 | "type" text 891 | , "user" text 892 | , database text 893 | , state text 894 | , addr text 895 | , port int 896 | , local_addr text 897 | , local_port int 898 | , connect_time timestamp with time zone 899 | , request_time timestamp with time zone 900 | , wait int 901 | , wait_us int 902 | , close_needed int 903 | , ptr text 904 | , link text 905 | , remote_pid int 906 | , tls text 907 | ); 908 | ELSE 909 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 910 | END IF; 911 | EXCEPTION 912 | WHEN connection_exception THEN 913 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 914 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 915 | ex_context = PG_EXCEPTION_CONTEXT, 916 | ex_detail = PG_EXCEPTION_DETAIL, 917 | ex_hint = PG_EXCEPTION_HINT; 918 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 919 | ORIGINAL ERROR: % 920 | CONTEXT: % 921 | DETAIL: % 922 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 923 | END; 924 | END LOOP; 925 | 926 | END 927 | $$; 928 | 929 | CREATE VIEW @extschema@.pgbouncer_servers AS 930 | SELECT pgbouncer_target_host 931 | "type" 932 | , "user" 933 | , database 934 | , state 935 | , addr 936 | , port 937 | , local_addr 938 | , local_port 939 | , connect_time 940 | , request_time 941 | , wait 942 | , wait_us 943 | , close_needed 944 | , ptr 945 | , link 946 | , remote_pid 947 | , tls 948 | , application_name 949 | FROM @extschema@.pgbouncer_servers_func(); 950 | 951 | 952 | /* 953 | * pgbouncer_sockets_func 954 | */ 955 | CREATE FUNCTION @extschema@.pgbouncer_sockets_func() RETURNS TABLE 956 | ( 957 | pgbouncer_target_host text 958 | , "type" text 959 | , "user" text 960 | , database text 961 | , state text 962 | , addr text 963 | , port int 964 | , local_addr text 965 | , local_port int 966 | , connect_time timestamp with time zone 967 | , request_time timestamp with time zone 968 | , wait int 969 | , wait_us int 970 | , close_needed int 971 | , ptr text 972 | , link text 973 | , remote_pid int 974 | , tls text 975 | , application_name text 976 | , recv_pos int 977 | , pkt_pos int 978 | , pkt_remain int 979 | , send_pos int 980 | , send_remain int 981 | , pkt_avail int 982 | , send_avail int 983 | ) 984 | LANGUAGE plpgsql 985 | AS $$ 986 | DECLARE 987 | ex_context text; 988 | ex_detail text; 989 | ex_hint text; 990 | ex_message text; 991 | v_row record; 992 | v_version_major int; 993 | v_version_minor int; 994 | BEGIN 995 | 996 | FOR v_row IN 997 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 998 | LOOP BEGIN 999 | SELECT version_major, version_minor 1000 | INTO v_version_major, v_version_minor 1001 | FROM @extschema@.pgbouncer_version_func(v_row.target_host); 1002 | 1003 | IF v_version_major >= 1 AND v_version_minor >= 18 THEN 1004 | RETURN QUERY SELECT 1005 | v_row.target_host AS pgbouncer_target_host 1006 | , x."type" 1007 | , x."user" 1008 | , x.database 1009 | , x.state 1010 | , x.addr 1011 | , x.port 1012 | , x.local_addr 1013 | , x.local_port 1014 | , x.connect_time 1015 | , x.request_time 1016 | , x.wait 1017 | , x.wait_us 1018 | , x.close_needed 1019 | , x.ptr 1020 | , x.link 1021 | , x.remote_pid 1022 | , x.tls 1023 | , x.application_name 1024 | , x.recv_pos 1025 | , x.pkt_pos 1026 | , x.pkt_remain 1027 | , x.send_pos 1028 | , x.send_remain 1029 | , x.pkt_avail 1030 | , x.send_avail 1031 | FROM dblink(v_row.target_host, 'show sockets') AS x 1032 | ( 1033 | "type" text 1034 | , "user" text 1035 | , database text 1036 | , state text 1037 | , addr text 1038 | , port int 1039 | , local_addr text 1040 | , local_port int 1041 | , connect_time timestamp with time zone 1042 | , request_time timestamp with time zone 1043 | , wait int 1044 | , wait_us int 1045 | , close_needed int 1046 | , ptr text 1047 | , link text 1048 | , remote_pid int 1049 | , tls text 1050 | , application_name text 1051 | , recv_pos int 1052 | , pkt_pos int 1053 | , pkt_remain int 1054 | , send_pos int 1055 | , send_remain int 1056 | , pkt_avail int 1057 | , send_avail int 1058 | ); 1059 | -- backward compatiblity floor is 1.17 1060 | ELSIF v_version_major = 1 AND v_version_minor = 17 THEN 1061 | RETURN QUERY SELECT 1062 | v_row.target_host AS pgbouncer_target_host 1063 | , x."type" 1064 | , x."user" 1065 | , x.database 1066 | , x.state 1067 | , x.addr 1068 | , x.port 1069 | , x.local_addr 1070 | , x.local_port 1071 | , x.connect_time 1072 | , x.request_time 1073 | , x.wait 1074 | , x.wait_us 1075 | , x.close_needed 1076 | , x.ptr 1077 | , x.link 1078 | , x.remote_pid 1079 | , x.tls 1080 | , '' AS application_name 1081 | , x.recv_pos 1082 | , x.pkt_pos 1083 | , x.pkt_remain 1084 | , x.send_pos 1085 | , x.send_remain 1086 | , x.pkt_avail 1087 | , x.send_avail 1088 | FROM dblink(v_row.target_host, 'show sockets') AS x 1089 | ( 1090 | "type" text 1091 | , "user" text 1092 | , database text 1093 | , state text 1094 | , addr text 1095 | , port int 1096 | , local_addr text 1097 | , local_port int 1098 | , connect_time timestamp with time zone 1099 | , request_time timestamp with time zone 1100 | , wait int 1101 | , wait_us int 1102 | , close_needed int 1103 | , ptr text 1104 | , link text 1105 | , remote_pid int 1106 | , tls text 1107 | , recv_pos int 1108 | , pkt_pos int 1109 | , pkt_remain int 1110 | , send_pos int 1111 | , send_remain int 1112 | , pkt_avail int 1113 | , send_avail int 1114 | ); 1115 | ELSE 1116 | RAISE EXCEPTION 'Encountered unsupported version of PgBouncer: %.%.x', v_version_major, v_version_minor; 1117 | END IF; 1118 | EXCEPTION 1119 | WHEN connection_exception THEN 1120 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 1121 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 1122 | ex_context = PG_EXCEPTION_CONTEXT, 1123 | ex_detail = PG_EXCEPTION_DETAIL, 1124 | ex_hint = PG_EXCEPTION_HINT; 1125 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 1126 | ORIGINAL ERROR: % 1127 | CONTEXT: % 1128 | DETAIL: % 1129 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 1130 | END; 1131 | END LOOP; 1132 | 1133 | END 1134 | $$; 1135 | 1136 | CREATE VIEW @extschema@.pgbouncer_sockets AS 1137 | SELECT pgbouncer_target_host 1138 | , "type" 1139 | , "user" 1140 | , database 1141 | , state 1142 | , addr 1143 | , port 1144 | , local_addr 1145 | , local_port 1146 | , connect_time 1147 | , request_time 1148 | , wait 1149 | , wait_us 1150 | , close_needed 1151 | , ptr 1152 | , link 1153 | , remote_pid 1154 | , tls 1155 | , application_name 1156 | , recv_pos 1157 | , pkt_pos 1158 | , pkt_remain 1159 | , send_pos 1160 | , send_remain 1161 | , pkt_avail 1162 | , send_avail 1163 | FROM @extschema@.pgbouncer_sockets_func(); 1164 | 1165 | 1166 | /* 1167 | * pgbouncer_stats_func 1168 | */ 1169 | CREATE FUNCTION @extschema@.pgbouncer_stats_func() RETURNS TABLE 1170 | ( 1171 | pgbouncer_target_host text 1172 | , database text 1173 | , total_xact_count bigint 1174 | , total_query_count bigint 1175 | , total_received bigint 1176 | , total_sent bigint 1177 | , total_xact_time bigint 1178 | , total_query_time bigint 1179 | , total_wait_time bigint 1180 | , avg_xact_count bigint 1181 | , avg_query_count bigint 1182 | , avg_recv bigint 1183 | , avg_sent bigint 1184 | , avg_xact_time bigint 1185 | , avg_query_time bigint 1186 | , avg_wait_time bigint 1187 | ) 1188 | LANGUAGE plpgsql 1189 | AS $$ 1190 | DECLARE 1191 | ex_context text; 1192 | ex_detail text; 1193 | ex_hint text; 1194 | ex_message text; 1195 | v_row record; 1196 | BEGIN 1197 | 1198 | FOR v_row IN 1199 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 1200 | LOOP BEGIN 1201 | 1202 | RETURN QUERY SELECT 1203 | v_row.target_host AS pgbouncer_target_host 1204 | , x.database 1205 | , x.total_xact_count 1206 | , x.total_query_count 1207 | , x.total_received 1208 | , x.total_sent 1209 | , x.total_xact_time 1210 | , x.total_query_time 1211 | , x.total_wait_time 1212 | , x.avg_xact_count 1213 | , x.avg_query_count 1214 | , x.avg_recv 1215 | , x.avg_sent 1216 | , x.avg_xact_time 1217 | , x.avg_query_time 1218 | , x.avg_wait_time 1219 | FROM dblink(v_row.target_host, 'show stats') AS x 1220 | ( 1221 | database text 1222 | , total_xact_count bigint 1223 | , total_query_count bigint 1224 | , total_received bigint 1225 | , total_sent bigint 1226 | , total_xact_time bigint 1227 | , total_query_time bigint 1228 | , total_wait_time bigint 1229 | , avg_xact_count bigint 1230 | , avg_query_count bigint 1231 | , avg_recv bigint 1232 | , avg_sent bigint 1233 | , avg_xact_time bigint 1234 | , avg_query_time bigint 1235 | , avg_wait_time bigint 1236 | ); 1237 | EXCEPTION 1238 | WHEN connection_exception THEN 1239 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 1240 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 1241 | ex_context = PG_EXCEPTION_CONTEXT, 1242 | ex_detail = PG_EXCEPTION_DETAIL, 1243 | ex_hint = PG_EXCEPTION_HINT; 1244 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 1245 | ORIGINAL ERROR: % 1246 | CONTEXT: % 1247 | DETAIL: % 1248 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 1249 | END; 1250 | END LOOP; 1251 | 1252 | END 1253 | $$; 1254 | 1255 | CREATE VIEW @extschema@.pgbouncer_stats AS 1256 | SELECT pgbouncer_target_host 1257 | , database 1258 | , total_xact_count 1259 | , total_query_count 1260 | , total_received 1261 | , total_sent 1262 | , total_xact_time 1263 | , total_query_time 1264 | , total_wait_time 1265 | , avg_xact_count 1266 | , avg_query_count 1267 | , avg_recv 1268 | , avg_sent 1269 | , avg_xact_time 1270 | , avg_query_time 1271 | , avg_wait_time 1272 | FROM @extschema@.pgbouncer_stats_func(); 1273 | 1274 | /* 1275 | * pgbouncer_users_func 1276 | */ 1277 | CREATE FUNCTION @extschema@.pgbouncer_users_func() RETURNS TABLE 1278 | ( 1279 | pgbouncer_target_host text 1280 | , name text 1281 | , pool_mode text 1282 | ) 1283 | LANGUAGE plpgsql 1284 | AS $$ 1285 | DECLARE 1286 | ex_context text; 1287 | ex_detail text; 1288 | ex_hint text; 1289 | ex_message text; 1290 | v_row record; 1291 | BEGIN 1292 | 1293 | FOR v_row IN 1294 | SELECT target_host FROM @extschema@.pgbouncer_fdw_targets WHERE active 1295 | LOOP BEGIN 1296 | 1297 | RETURN QUERY SELECT 1298 | v_row.target_host AS pgbouncer_target_host 1299 | , x.name 1300 | , x.pool_mode 1301 | FROM dblink(v_row.target_host, 'show users') AS x 1302 | ( 1303 | name text 1304 | , pool_mode text 1305 | ); 1306 | EXCEPTION 1307 | WHEN connection_exception THEN 1308 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts.', v_row.target_host; 1309 | GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, 1310 | ex_context = PG_EXCEPTION_CONTEXT, 1311 | ex_detail = PG_EXCEPTION_DETAIL, 1312 | ex_hint = PG_EXCEPTION_HINT; 1313 | RAISE WARNING 'pgbouncer_fdw: Unable to establish connection to pgBouncer target host: %. Continuing to additional hosts. 1314 | ORIGINAL ERROR: % 1315 | CONTEXT: % 1316 | DETAIL: % 1317 | HINT: %', v_row.target_host, ex_message, ex_context, ex_detail, ex_hint; 1318 | END; 1319 | END LOOP; 1320 | END 1321 | $$; 1322 | 1323 | CREATE VIEW @extschema@.pgbouncer_users AS 1324 | SELECT pgbouncer_target_host 1325 | , name 1326 | , pool_mode 1327 | FROM @extschema@.pgbouncer_users_func(); 1328 | 1329 | 1330 | /**** ADMIN FUNCTIONS */ 1331 | 1332 | CREATE FUNCTION @extschema@.pgbouncer_command_disable(p_dbname text, p_pgbouncer_target_host text DEFAULT 'pgbouncer') RETURNS void 1333 | LANGUAGE plpgsql 1334 | AS $$ 1335 | BEGIN 1336 | PERFORM dblink_exec(p_pgbouncer_target_host, format('DISABLE %I', p_dbname)); 1337 | END 1338 | $$; 1339 | 1340 | CREATE FUNCTION @extschema@.pgbouncer_command_enable(p_dbname text, p_pgbouncer_target_host text DEFAULT 'pgbouncer') RETURNS void 1341 | LANGUAGE plpgsql 1342 | AS $$ 1343 | BEGIN 1344 | PERFORM dblink_exec(p_pgbouncer_target_host, format('ENABLE %I', p_dbname)); 1345 | END 1346 | $$; 1347 | 1348 | CREATE FUNCTION @extschema@.pgbouncer_command_kill(p_dbname text DEFAULT NULL, p_pgbouncer_target_host text DEFAULT 'pgbouncer') RETURNS void 1349 | LANGUAGE plpgsql 1350 | AS $$ 1351 | BEGIN 1352 | IF p_dbname IS NULL THEN 1353 | PERFORM dblink_exec(p_pgbouncer_target_host, 'KILL'); 1354 | ELSE 1355 | PERFORM dblink_exec(p_pgbouncer_target_host, format('KILL %I', p_dbname)); 1356 | END IF; 1357 | END 1358 | $$; 1359 | 1360 | CREATE FUNCTION @extschema@.pgbouncer_command_pause(p_dbname text DEFAULT NULL, p_pgbouncer_target_host text DEFAULT 'pgbouncer') RETURNS void 1361 | LANGUAGE plpgsql 1362 | AS $$ 1363 | BEGIN 1364 | IF p_dbname IS NULL THEN 1365 | PERFORM dblink_exec(p_pgbouncer_target_host, 'PAUSE'); 1366 | ELSE 1367 | PERFORM dblink_exec(p_pgbouncer_target_host, format('PAUSE %I', p_dbname)); 1368 | END IF; 1369 | END 1370 | $$; 1371 | 1372 | CREATE FUNCTION @extschema@.pgbouncer_command_reconnect(p_dbname text DEFAULT NULL, p_pgbouncer_target_host text DEFAULT 'pgbouncer') RETURNS void 1373 | LANGUAGE plpgsql 1374 | AS $$ 1375 | BEGIN 1376 | IF p_dbname IS NULL THEN 1377 | PERFORM dblink_exec(p_pgbouncer_target_host, 'RECONNECT'); 1378 | ELSE 1379 | PERFORM dblink_exec(p_pgbouncer_target_host, format('RECONNECT %I', p_dbname)); 1380 | END IF; 1381 | END 1382 | $$; 1383 | 1384 | CREATE FUNCTION @extschema@.pgbouncer_command_reload(p_pgbouncer_target_host text DEFAULT 'pgbouncer') RETURNS void 1385 | LANGUAGE plpgsql 1386 | AS $$ 1387 | BEGIN 1388 | PERFORM dblink_exec(p_pgbouncer_target_host, 'RELOAD'); 1389 | END 1390 | $$; 1391 | 1392 | CREATE FUNCTION @extschema@.pgbouncer_command_resume(p_dbname text DEFAULT NULL, p_pgbouncer_target_host text DEFAULT 'pgbouncer') RETURNS void 1393 | LANGUAGE plpgsql 1394 | AS $$ 1395 | BEGIN 1396 | IF p_dbname IS NULL THEN 1397 | PERFORM dblink_exec(p_pgbouncer_target_host, 'RESUME'); 1398 | ELSE 1399 | PERFORM dblink_exec(p_pgbouncer_target_host, format('RESUME %I', p_dbname)); 1400 | END IF; 1401 | END 1402 | $$; 1403 | 1404 | CREATE FUNCTION @extschema@.pgbouncer_command_set(p_name text, p_value text, p_pgbouncer_target_host text DEFAULT 'pgbouncer') RETURNS void 1405 | LANGUAGE plpgsql 1406 | AS $$ 1407 | BEGIN 1408 | PERFORM dblink_exec(p_pgbouncer_target_host, format('SET %s = %L', p_name, p_value)); 1409 | END 1410 | $$; 1411 | 1412 | CREATE FUNCTION @extschema@.pgbouncer_command_shutdown(p_pgbouncer_target_host text DEFAULT 'pgbouncer') RETURNS void 1413 | LANGUAGE plpgsql 1414 | AS $$ 1415 | BEGIN 1416 | PERFORM dblink_exec(p_pgbouncer_target_host, 'shutdown'); 1417 | END 1418 | $$; 1419 | 1420 | CREATE FUNCTION @extschema@.pgbouncer_command_suspend(p_pgbouncer_target_host text DEFAULT 'pgbouncer') RETURNS void 1421 | LANGUAGE plpgsql 1422 | AS $$ 1423 | BEGIN 1424 | PERFORM dblink_exec(p_pgbouncer_target_host, 'SUSPEND'); 1425 | END 1426 | $$; 1427 | 1428 | CREATE FUNCTION @extschema@.pgbouncer_command_wait_close(p_dbname text DEFAULT NULL, p_pgbouncer_target_host text DEFAULT 'pgbouncer') RETURNS void 1429 | LANGUAGE plpgsql 1430 | AS $$ 1431 | BEGIN 1432 | IF p_dbname IS NULL THEN 1433 | PERFORM dblink_exec(p_pgbouncer_target_host, 'WAIT_CLOSE'); 1434 | ELSE 1435 | PERFORM dblink_exec(p_pgbouncer_target_host, format('WAIT_CLOSE %I', p_dbname)); 1436 | END IF; 1437 | END 1438 | $$; 1439 | 1440 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_disable(text, text) FROM PUBLIC; 1441 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_enable(text, text) FROM PUBLIC; 1442 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_kill(text, text) FROM PUBLIC; 1443 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_pause(text, text) FROM PUBLIC; 1444 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_reconnect(text, text) FROM PUBLIC; 1445 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_reload(text) FROM PUBLIC; 1446 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_resume(text, text) FROM PUBLIC; 1447 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_set(text, text, text) FROM PUBLIC; 1448 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_shutdown(text) FROM PUBLIC; 1449 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_suspend(text) FROM PUBLIC; 1450 | REVOKE EXECUTE ON FUNCTION @extschema@.pgbouncer_command_wait_close(text, text) FROM PUBLIC; 1451 | 1452 | --------------------------------------------------------------------------------