diff --git a/roles/pgsql/templates/pg-init-template.sql b/roles/pgsql/templates/pg-init-template.sql index 75f13c1b..9365a463 100644 --- a/roles/pgsql/templates/pg-init-template.sql +++ b/roles/pgsql/templates/pg-init-template.sql @@ -143,93 +143,100 @@ GRANT EXECUTE ON FUNCTION monitor.beating() TO pg_monitor; ---------------------------------------------------------------------- -- Table bloat estimate : monitor.pg_table_bloat ---------------------------------------------------------------------- +DROP FUNCTION IF EXISTS monitor.pg_table_bloat() CASCADE; +DROP FUNCTION IF EXISTS monitor.pg_index_bloat() CASCADE; DROP VIEW IF EXISTS monitor.pg_table_bloat CASCADE; -CREATE OR REPLACE VIEW monitor.pg_table_bloat AS -SELECT CURRENT_CATALOG AS datname, nspname, relname , tblid , bs * tblpages AS size, - CASE WHEN tblpages - est_tblpages_ff > 0 THEN (tblpages - est_tblpages_ff)/tblpages::FLOAT ELSE 0 END AS ratio -FROM ( - SELECT ceil( reltuples / ( (bs-page_hdr)*fillfactor/(tpl_size*100) ) ) + ceil( toasttuples / 4 ) AS est_tblpages_ff, - tblpages, fillfactor, bs, tblid, nspname, relname, is_na - FROM ( - SELECT - ( 4 + tpl_hdr_size + tpl_data_size + (2 * ma) - - CASE WHEN tpl_hdr_size % ma = 0 THEN ma ELSE tpl_hdr_size % ma END - - CASE WHEN ceil(tpl_data_size)::INT % ma = 0 THEN ma ELSE ceil(tpl_data_size)::INT % ma END - ) AS tpl_size, (heappages + toastpages) AS tblpages, heappages, - toastpages, reltuples, toasttuples, bs, page_hdr, tblid, nspname, relname, fillfactor, is_na - FROM ( - SELECT - tbl.oid AS tblid, ns.nspname , tbl.relname, tbl.reltuples, - tbl.relpages AS heappages, coalesce(toast.relpages, 0) AS toastpages, - coalesce(toast.reltuples, 0) AS toasttuples, - coalesce(substring(array_to_string(tbl.reloptions, ' ') FROM 'fillfactor=([0-9]+)')::smallint, 100) AS fillfactor, - current_setting('block_size')::numeric AS bs, - CASE WHEN version()~'mingw32' OR version()~'64-bit|x86_64|ppc64|ia64|amd64' THEN 8 ELSE 4 END AS ma, - 24 AS page_hdr, - 23 + CASE WHEN MAX(coalesce(s.null_frac,0)) > 0 THEN ( 7 + count(s.attname) ) / 8 ELSE 0::int END - + CASE WHEN bool_or(att.attname = 'oid' and att.attnum < 0) THEN 4 ELSE 0 END AS tpl_hdr_size, - sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 0) ) AS tpl_data_size, - bool_or(att.atttypid = 'pg_catalog.name'::regtype) - OR sum(CASE WHEN att.attnum > 0 THEN 1 ELSE 0 END) <> count(s.attname) AS is_na - FROM pg_attribute AS att - JOIN pg_class AS tbl ON att.attrelid = tbl.oid - JOIN pg_namespace AS ns ON ns.oid = tbl.relnamespace - LEFT JOIN pg_stats AS s ON s.schemaname=ns.nspname AND s.tablename = tbl.relname AND s.inherited=false AND s.attname=att.attname - LEFT JOIN pg_class AS toast ON tbl.reltoastrelid = toast.oid - WHERE NOT att.attisdropped AND tbl.relkind = 'r' AND nspname NOT IN ('pg_catalog','information_schema') - GROUP BY tbl.oid, ns.nspname, tbl.relname, tbl.reltuples, tbl.relpages, toast.relpages, toast.reltuples, tbl.reloptions - ) AS s - ) AS s2 - ) AS s3 -WHERE NOT is_na; -COMMENT ON VIEW monitor.pg_table_bloat IS 'postgres table bloat estimate'; +DROP VIEW IF EXISTS monitor.pg_index_bloat CASCADE; -GRANT SELECT ON monitor.pg_table_bloat TO pg_monitor; +-- table bloat func +CREATE OR REPLACE FUNCTION monitor.pg_table_bloat() + RETURNS TABLE(datname TEXT,nspname TEXT,relname TEXT,tblid OID,size BIGINT,ratio FLOAT) AS +$$SELECT CURRENT_CATALOG AS datname, nspname, relname , tblid , bs * tblpages AS size, + CASE WHEN tblpages - est_tblpages_ff > 0 THEN (tblpages - est_tblpages_ff)/tblpages::FLOAT ELSE 0 END AS ratio + FROM ( + SELECT ceil( reltuples / ( (bs-page_hdr)*fillfactor/(tpl_size*100) ) ) + ceil( toasttuples / 4 ) AS est_tblpages_ff, + tblpages, fillfactor, bs, tblid, nspname, relname, is_na + FROM ( + SELECT + ( 4 + tpl_hdr_size + tpl_data_size + (2 * ma) + - CASE WHEN tpl_hdr_size % ma = 0 THEN ma ELSE tpl_hdr_size % ma END + - CASE WHEN ceil(tpl_data_size)::INT % ma = 0 THEN ma ELSE ceil(tpl_data_size)::INT % ma END + ) AS tpl_size, (heappages + toastpages) AS tblpages, heappages, + toastpages, reltuples, toasttuples, bs, page_hdr, tblid, nspname, relname, fillfactor, is_na + FROM ( + SELECT + tbl.oid AS tblid, ns.nspname , tbl.relname, tbl.reltuples, + tbl.relpages AS heappages, coalesce(toast.relpages, 0) AS toastpages, + coalesce(toast.reltuples, 0) AS toasttuples, + coalesce(substring(array_to_string(tbl.reloptions, ' ') FROM 'fillfactor=([0-9]+)')::smallint, 100) AS fillfactor, + current_setting('block_size')::numeric AS bs, + CASE WHEN version()~'mingw32' OR version()~'64-bit|x86_64|ppc64|ia64|amd64' THEN 8 ELSE 4 END AS ma, + 24 AS page_hdr, + 23 + CASE WHEN MAX(coalesce(s.null_frac,0)) > 0 THEN ( 7 + count(s.attname) ) / 8 ELSE 0::int END + + CASE WHEN bool_or(att.attname = 'oid' and att.attnum < 0) THEN 4 ELSE 0 END AS tpl_hdr_size, + sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 0) ) AS tpl_data_size, + bool_or(att.atttypid = 'pg_catalog.name'::regtype) + OR sum(CASE WHEN att.attnum > 0 THEN 1 ELSE 0 END) <> count(s.attname) AS is_na + FROM pg_attribute AS att + JOIN pg_class AS tbl ON att.attrelid = tbl.oid + JOIN pg_namespace AS ns ON ns.oid = tbl.relnamespace + LEFT JOIN pg_stats AS s ON s.schemaname=ns.nspname AND s.tablename = tbl.relname AND s.inherited=false AND s.attname=att.attname + LEFT JOIN pg_class AS toast ON tbl.reltoastrelid = toast.oid + WHERE NOT att.attisdropped AND tbl.relkind = 'r' AND nspname NOT IN ('pg_catalog','information_schema') + GROUP BY tbl.oid, ns.nspname, tbl.relname, tbl.reltuples, tbl.relpages, toast.relpages, toast.reltuples, tbl.reloptions + ) AS s + ) AS s2 + ) AS s3 + WHERE NOT is_na; +$$ LANGUAGE SQL SECURITY DEFINER; + +-- index bloat func +CREATE OR REPLACE FUNCTION monitor.pg_index_bloat() + RETURNS TABLE(datname TEXT,nspname TEXT,relname TEXT,tblid OID,idxid OID,size BIGINT,ratio FLOAT) AS +$$ SELECT CURRENT_CATALOG AS datname, nspname, idxname AS relname, tblid, idxid, + relpages::BIGINT * bs AS size, + COALESCE((relpages - ( reltuples * (6 + ma - (CASE WHEN index_tuple_hdr % ma = 0 THEN ma ELSE index_tuple_hdr % ma END) + + nulldatawidth + ma - (CASE WHEN nulldatawidth % ma = 0 THEN ma ELSE nulldatawidth % ma END)) + / (bs - pagehdr)::FLOAT + 1 )), 0) / relpages::FLOAT AS ratio + FROM ( + SELECT nspname, idxname, indrelid AS tblid, indexrelid AS idxid, + reltuples, relpages, + current_setting('block_size')::INTEGER AS bs, + (CASE WHEN version() ~ 'mingw32' OR version() ~ '64-bit|x86_64|ppc64|ia64|amd64' THEN 8 ELSE 4 END) AS ma, + 24 AS pagehdr, + (CASE WHEN max(COALESCE(pg_stats.null_frac, 0)) = 0 THEN 2 ELSE 6 END) AS index_tuple_hdr, + sum((1.0 - COALESCE(pg_stats.null_frac, 0.0)) * + COALESCE(pg_stats.avg_width, 1024))::INTEGER AS nulldatawidth + FROM pg_attribute + JOIN ( + SELECT pg_namespace.nspname, ic.relname AS idxname, ic.reltuples, ic.relpages, pg_index.indrelid, + pg_index.indexrelid, tc.relname AS tablename, + regexp_split_to_table(pg_index.indkey::TEXT, ' ')::INTEGER AS attnum, + pg_index.indexrelid AS index_oid + FROM pg_index + JOIN pg_class ic ON pg_index.indexrelid = ic.oid + JOIN pg_class tc ON pg_index.indrelid = tc.oid + JOIN pg_namespace ON ic.relnamespace = pg_namespace.oid + JOIN pg_am ON ic.relam = pg_am.oid + WHERE pg_am.amname = 'btree' AND ic.relpages > 0 AND pg_namespace.nspname NOT IN ('pg_catalog', 'information_schema') + ) ind_atts ON pg_attribute.attrelid = ind_atts.indexrelid AND pg_attribute.attnum = ind_atts.attnum + JOIN pg_stats ON pg_stats.schemaname = ind_atts.nspname + AND ((pg_stats.tablename = ind_atts.tablename AND pg_stats.attname = pg_get_indexdef(pg_attribute.attrelid, pg_attribute.attnum, TRUE)) + OR (pg_stats.tablename = ind_atts.idxname AND pg_stats.attname = pg_attribute.attname)) + WHERE pg_attribute.attnum > 0 + GROUP BY nspname, idxname, indrelid, indexrelid, reltuples, relpages + ) est +$$ LANGUAGE SQL SECURITY DEFINER; + +CREATE OR REPLACE VIEW monitor.pg_table_bloat AS SELECT * FROM monitor.pg_table_bloat(); +COMMENT ON VIEW monitor.pg_table_bloat IS 'postgres table bloat estimate'; ----------------------------------------------------------------------- --- Index bloat estimate : monitor.pg_index_bloat ----------------------------------------------------------------------- -DROP VIEW IF EXISTS monitor.pg_index_bloat CASCADE; -CREATE OR REPLACE VIEW monitor.pg_index_bloat AS -SELECT CURRENT_CATALOG AS datname, nspname, idxname AS relname, tblid, idxid, relpages::BIGINT * bs AS size, - COALESCE((relpages - ( reltuples * (6 + ma - (CASE WHEN index_tuple_hdr % ma = 0 THEN ma ELSE index_tuple_hdr % ma END) - + nulldatawidth + ma - (CASE WHEN nulldatawidth % ma = 0 THEN ma ELSE nulldatawidth % ma END)) - / (bs - pagehdr)::FLOAT + 1 )), 0) / relpages::FLOAT AS ratio -FROM ( - SELECT nspname,idxname,indrelid AS tblid,indexrelid AS idxid, - reltuples,relpages, - current_setting('block_size')::INTEGER AS bs, - (CASE WHEN version() ~ 'mingw32' OR version() ~ '64-bit|x86_64|ppc64|ia64|amd64' THEN 8 ELSE 4 END) AS ma, - 24 AS pagehdr, - (CASE WHEN max(COALESCE(pg_stats.null_frac, 0)) = 0 THEN 2 ELSE 6 END) AS index_tuple_hdr, - sum((1.0 - COALESCE(pg_stats.null_frac, 0.0)) * - COALESCE(pg_stats.avg_width, 1024))::INTEGER AS nulldatawidth - FROM pg_attribute - JOIN ( - SELECT pg_namespace.nspname, - ic.relname AS idxname, - ic.reltuples, - ic.relpages, - pg_index.indrelid, - pg_index.indexrelid, - tc.relname AS tablename, - regexp_split_to_table(pg_index.indkey::TEXT, ' ') :: INTEGER AS attnum, - pg_index.indexrelid AS index_oid - FROM pg_index - JOIN pg_class ic ON pg_index.indexrelid = ic.oid - JOIN pg_class tc ON pg_index.indrelid = tc.oid - JOIN pg_namespace ON pg_namespace.oid = ic.relnamespace - JOIN pg_am ON ic.relam = pg_am.oid - WHERE pg_am.amname = 'btree' AND ic.relpages > 0 AND nspname NOT IN ('pg_catalog', 'information_schema') - ) ind_atts ON pg_attribute.attrelid = ind_atts.indexrelid AND pg_attribute.attnum = ind_atts.attnum - JOIN pg_stats ON pg_stats.schemaname = ind_atts.nspname - AND ((pg_stats.tablename = ind_atts.tablename AND pg_stats.attname = pg_get_indexdef(pg_attribute.attrelid, pg_attribute.attnum, TRUE)) - OR (pg_stats.tablename = ind_atts.idxname AND pg_stats.attname = pg_attribute.attname)) - WHERE pg_attribute.attnum > 0 - GROUP BY nspname,idxname,indrelid,indexrelid,reltuples,relpages - ) est; -COMMENT ON VIEW monitor.pg_index_bloat IS 'postgres index bloat estimate (btree-only)'; +CREATE OR REPLACE VIEW monitor.pg_index_bloat AS SELECT * FROM monitor.pg_index_bloat(); +COMMENT ON VIEW monitor.pg_index_bloat IS 'postgres index bloat estimate (btree)'; +GRANT EXECUTE ON FUNCTION monitor.pg_table_bloat() TO pg_monitor; +GRANT EXECUTE ON FUNCTION monitor.pg_index_bloat() TO pg_monitor; +GRANT SELECT ON monitor.pg_table_bloat TO pg_monitor; GRANT SELECT ON monitor.pg_index_bloat TO pg_monitor; ---------------------------------------------------------------------- @@ -425,7 +432,7 @@ GRANT SELECT ON monitor.pg_lock_waiting TO pg_monitor; ---------------------------------------------------------------------- DROP FUNCTION IF EXISTS monitor.pg_shmem() CASCADE; CREATE OR REPLACE FUNCTION monitor.pg_shmem() RETURNS SETOF - pg_shmem_allocations AS $$ SELECT * FROM pg_shmem_allocations;$$ LANGUAGE SQL SECURITY DEFINER; + pg_shmem_allocations AS $$SELECT * FROM pg_shmem_allocations;$$ LANGUAGE SQL SECURITY DEFINER; COMMENT ON FUNCTION monitor.pg_shmem() IS 'security wrapper for system view pg_shmem'; REVOKE ALL ON FUNCTION monitor.pg_shmem() FROM PUBLIC; REVOKE ALL ON FUNCTION monitor.pg_shmem() FROM dbrole_readonly; @@ -658,7 +665,6 @@ GRANT SELECT ON monitor.disk_free TO pg_monitor; --==================================================================-- -- Customize Logic -- --==================================================================-- --- This script will be execute on primary instance among a newly created +-- This script will be executed on primary instance among a newly created -- postgres cluster. it will be executed as dbsu on template1 database --- put your own customize logic here --- make sure they are idempotent \ No newline at end of file +-- put your own customize logic here, and make sure they are idempotent \ No newline at end of file