├── COPYRIGHT ├── LICENSE ├── README.md ├── index_watch_functions.sql └── index_watch_tables.sql /COPYRIGHT: -------------------------------------------------------------------------------- 1 | Portions Copyright (c) 2021-2022, Maxim Boguk 2 | All rights reserved. 3 | 4 | Redistribution and use in source and binary forms, with or without 5 | modification, are permitted provided that the following conditions are met: 6 | 7 | * Redistributions of source code must retain the above copyright notice, 8 | this list of conditions and the following disclaimer. 9 | * Redistributions in binary form must reproduce the above copyright 10 | notice, this list of conditions and the following disclaimer in the 11 | documentation and/or other materials provided with the distribution. 12 | * Neither the name of the authors nor the names of its contributors may 13 | be used to endorse or promote products derived from this software 14 | without specific prior written permission. 15 | 16 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" 17 | AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE 18 | IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 19 | DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE 20 | FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL 21 | DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR 22 | SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER 23 | CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, 24 | OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE 25 | OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 26 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | BSD 3-Clause License 2 | 3 | Copyright (c) 2020-2023, Maxim Boguk (Maxim.Boguk@gmail.com) 4 | 5 | Redistribution and use in source and binary forms, with or without 6 | modification, are permitted provided that the following conditions are met: 7 | 8 | 1. Redistributions of source code must retain the above copyright notice, this 9 | list of conditions and the following disclaimer. 10 | 11 | 2. Redistributions in binary form must reproduce the above copyright notice, 12 | this list of conditions and the following disclaimer in the documentation 13 | and/or other materials provided with the distribution. 14 | 15 | 3. Neither the name of the copyright holder nor the names of its 16 | contributors may be used to endorse or promote products derived from 17 | this software without specific prior written permission. 18 | 19 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" 20 | AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE 21 | IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 22 | DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE 23 | FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL 24 | DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR 25 | SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER 26 | CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, 27 | OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE 28 | OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 29 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | Utility for automatical rebuild of bloated indexes (a-la smart autovacuum to deal with index bloat) in PostgreSQL. 2 | 3 | ## Program purpose 4 | Uncontrollable index bloat on frequently updated tables is a known issue in PostgreSQL. 5 | The built-in autovacuum doesn’t deal well with bloat regardless of its settings.  6 | pg_index_watch resolves this issue by automatically rebuilding indexes when needed.  7 | 8 | ## Where to get support 9 | create github issue 10 | or email maxim.boguk@dataegret.com 11 | or write in telegram channel https://t.me/pg_index_watch_support 12 | 13 | 14 | ## Concept 15 | With the introduction of REINDEX CONCURRENTLY in PostgreSQL 12 there is now a safe and (almost) lock-free way to rebuild bloated indexes. 16 | Despite that, the question remaines - based on which criteria do we determine a bloat and whether there is a need to rebuild the index. 17 | The pg_index_watch utilizes the ratio between index size and pg_class.reltuples (which is kept up-to-date with help of autovacuum/autoanalyze) to determine the extent of index bloat relative to the ideal situation of the newly built index. 18 | It also allows rebuilding bloated indexes of any type without dependency on pgstattuple for estimating index bloat. 19 | 20 | pg_index_watch offers following approach to this problem: 21 | 22 | PostgreSQL allows you to access (and almost free of charge): 23 | 1) number of rows in the index (in pg_class.reltuples for the index) and 2) index size. 24 | 25 | Further on, assuming that the ratio of index size to the number of entries is constant (this is correct in 99.9% of cases), we can speculate that if, compared to its regular state, the ratio has doubled is is most certainly that the index have bloated 2x. 26 | 27 | Next, we receive a similar to autovacuum system that automatically tracks level of index bloat and rebuilds (via REINDEX CONCURRENTLY) them as needed. 28 | 29 | 30 | ## Basic requirements for installation and usage: 31 | • PostgreSQL version 12.0 or higher 32 | • Superuser access to the database with the possibility writing cron from the current user  33 | ◦ psql access is sufficient 34 | ◦ Root or sudo to PostgreSQL isn’t required 35 | • Possibility of passwordless or ~/.pgpass access on behalf of superuser to all local databases 36 | (i.e. you should be able to run psql -U postgres -d datname without entering the password.) 37 | 38 | ## Recommendations  39 | • If server resources allow set non-zero max_parallel_maintenance_workers (exact amount depends on server parameters). 40 | • To set wal_keep_segments to at least 5000, unless the wal archive is used to support streaming replication. 41 | 42 | ## Installation (as PostgreSQL user) 43 | 44 | # get the code git clone 45 | ``` 46 | git clone https://github.com/dataegret/pg_index_watch 47 | cd pg_index_watch 48 | #create tables’ structure 49 | psql -1 -d postgres -f index_watch_tables.sql 50 | #importing the code (stored procedures) 51 | psql -1 -d postgres -f index_watch_functions.sql 52 | ``` 53 | 54 | ## The initial launch 55 | 56 | IMPORTANT!!! During the FIRST (and ONLY FIRST) launch ALL!! the indexes that are bigger than 10MB (default setting) will be rebuilt.   57 | This process might take several hours (or even days). 58 | On the large databases (sized several TB) I suggest performing the FIRST launch manually. 59 | After that, only bloated indexes will be processed. 60 | 61 | ``` 62 | nohup psql -d postgres -qt -c "CALL index_watch.periodic(TRUE);" >> index_watch.log 63 | ``` 64 | 65 | 66 | ## Automated work following the installation 67 | Set up the cron daily, for example at midnight (from superuser of the database = normally postgres) or hourly if there is a high number of writes to a database.  68 | 69 | IMPORTANT!!! It’s highly advisable to make sure that the time doesn’t coincide with pg_dump and other long maintenance tasks. 70 | 71 | ``` 72 | 00 00 * * *   psql -d postgres -AtqXc "select not pg_is_in_recovery();" | grep -qx t || exit; psql -d postgres -qt -c "CALL index_watch.periodic(TRUE);" 73 | ``` 74 | 75 | ## UPDATE to new versions (from a postgres user) 76 | ``` 77 | cd pg_index_watch 78 | git pull 79 | #load updated codebase 80 | psql -1 -d postgres -f index_watch_functions.sql 81 | index_watch table structure update will be performed AUTOMATICALLY (if needed) with the next index_watch.periodic command. 82 | ``` 83 | 84 | However, you can manually update tables structure to the current version (normally, this is not required): 85 | 86 | ``` 87 | psql -1 -d postgres -c "SELECT index_watch.check_update_structure_version()" 88 | ``` 89 | 90 | ## Viewing reindexing history (it is renewed during the initial launch and with launch from crons):  91 | ``` 92 | psql -1 -d postgres -c "SELECT * FROM index_watch.history LIMIT 20" 93 | ``` 94 | 95 | ## review of current bloat status in   96 | specific database DB_NAME: 97 | Assumes that cron index_watch.periodic WORKS, otherwise data will not be updated. 98 | 99 | ``` 100 | psql -1 -d postgres -c "select * from index_watch.get_index_bloat_estimates('DB_NAME') order by estimated_bloat desc nulls last limit 40;" 101 | ``` 102 | 103 | ## list of user callable functions and arguments 104 | 105 | ### index_watch.version() 106 | FUNCTION index_watch.version() RETURNS TEXT 107 | returns installed pg_index_watch version 108 | 109 | ### index_watch.check_update_structure_version() 110 | FUNCTION index_watch.check_update_structure_version() RETURNS VOID 111 | update index watch table structure to the current version 112 | 113 | ### index_watch.get_setting 114 | FUNCTION index_watch.get_setting(_datname text, _schemaname text, _relname text, _indexrelname text, _key TEXT) RETURNS TEXT 115 | returns configuration value for given database, schema, table, index and setting name 116 | 117 | ### index_watch.set_or_replace_setting 118 | FUNCTION index_watch.set_or_replace_setting(_datname text, _schemaname text, _relname text, _indexrelname text, _key TEXT, _value text, _comment text) RETURNS VOID 119 | set or replace setting value for given database, schema, table, index and setting name 120 | 121 | ### index_watch.get_index_bloat_estimates 122 | FUNCTION index_watch.get_index_bloat_estimates(_datname name) RETURNS TABLE(datname name, schemaname name, relname name, indexrelname name, indexsize bigint, estimated_bloat real) 123 | returns table of current estimated index bloat for given database 124 | 125 | ### index_watch.do_force_populate_index_stats 126 | FUNCTION index_watch.do_force_populate_index_stats(_datname name, _schemaname name, _relname name, _indexrelname name) RETURNS VOID 127 | forced populate of best index ratio for given database, schema, table, index without mandatory reindexing (useful if new huge index just created and definitely don't have any bloat or after pg_restore and similar cases 128 | 129 | ### index_watch.do_reindex 130 | PROCEDURE index_watch.do_reindex(_datname name, _schemaname name, _relname name, _indexrelname name, _force BOOLEAN DEFAULT FALSE) 131 | perform reindex of bloated indexes in given database, schema, table, index (or every suitable indexes with _force=>true) 132 | 133 | ### index_watch.periodic 134 | PROCEDURE index_watch.periodic(real_run BOOLEAN DEFAULT FALSE, force BOOLEAN DEFAULT FALSE) AS 135 | perform bloat based reindex of every accessible database in cluster 136 | 137 | 138 | ## todo 139 | Add docmentation/howto about working with advanced settings and custom configuration of utility. 140 | Add support of watching remote databases. 141 | Add better commentaries to code. 142 | 143 | -------------------------------------------------------------------------------- /index_watch_functions.sql: -------------------------------------------------------------------------------- 1 | \set ON_ERROR_STOP 2 | 3 | --disable useless (in this particular case) NOTICE noise 4 | set client_min_messages to WARNING; 5 | 6 | DROP FUNCTION IF EXISTS index_watch.check_pg_version_bugfixed(); 7 | CREATE OR REPLACE FUNCTION index_watch._check_pg_version_bugfixed() 8 | RETURNS BOOLEAN AS 9 | $BODY$ 10 | BEGIN 11 | IF ((current_setting('server_version_num')::INTEGER >= 120010) AND 12 | (current_setting('server_version_num')::INTEGER < 130000)) OR 13 | ((current_setting('server_version_num')::INTEGER >= 130006) AND 14 | (current_setting('server_version_num')::INTEGER < 140000)) OR 15 | (current_setting('server_version_num')::INTEGER >= 140002) 16 | THEN RETURN TRUE; 17 | ELSE RETURN FALSE; 18 | END IF; 19 | END; 20 | $BODY$ 21 | LANGUAGE plpgsql; 22 | 23 | 24 | DROP FUNCTION IF EXISTS index_watch.check_pg14_version_bugfixed(); 25 | CREATE OR REPLACE FUNCTION index_watch._check_pg14_version_bugfixed() 26 | RETURNS BOOLEAN AS 27 | $BODY$ 28 | BEGIN 29 | IF (current_setting('server_version_num')::INTEGER >= 140000) AND 30 | (current_setting('server_version_num')::INTEGER < 140004) 31 | THEN RETURN FALSE; 32 | ELSE RETURN TRUE; 33 | END IF; 34 | END; 35 | $BODY$ 36 | LANGUAGE plpgsql; 37 | 38 | 39 | DO $$ 40 | BEGIN 41 | IF current_setting('server_version_num')<'12' 42 | THEN 43 | RAISE 'This library works only for PostgreSQL 12 or higher!'; 44 | ELSE 45 | IF NOT index_watch._check_pg_version_bugfixed() 46 | THEN 47 | RAISE WARNING 'The database version % affected by PostgreSQL bugs which make use pg_index_watch potentially unsafe, please update to latest minor release. For additional info please see: 48 | https://www.postgresql.org/message-id/E1mumI4-0001Zp-PB@gemulon.postgresql.org 49 | and 50 | https://www.postgresql.org/message-id/E1n8C7O-00066j-Q5@gemulon.postgresql.org', 51 | current_setting('server_version'); 52 | END IF; 53 | IF NOT index_watch._check_pg14_version_bugfixed() 54 | THEN 55 | RAISE WARNING 'The database version % affected by PostgreSQL bug BUG #17485 which make use pg_index_watch unsafe, please update to latest minor release. For additional info please see: 56 | https://www.postgresql.org/message-id/202205251144.6t4urostzc3s@alvherre.pgsql', 57 | current_setting('server_version'); 58 | END IF; 59 | END IF; 60 | END; $$; 61 | 62 | 63 | CREATE EXTENSION IF NOT EXISTS dblink; 64 | ALTER EXTENSION dblink UPDATE; 65 | 66 | --current version of code 67 | CREATE OR REPLACE FUNCTION index_watch.version() 68 | RETURNS TEXT AS 69 | $BODY$ 70 | BEGIN 71 | RETURN '1.03'; 72 | END; 73 | $BODY$ 74 | LANGUAGE plpgsql IMMUTABLE; 75 | 76 | 77 | 78 | --minimum table structure version required 79 | CREATE OR REPLACE FUNCTION index_watch._check_structure_version() 80 | RETURNS VOID AS 81 | $BODY$ 82 | DECLARE 83 | _tables_version INTEGER; 84 | _required_version INTEGER := 8; 85 | BEGIN 86 | SELECT version INTO STRICT _tables_version FROM index_watch.tables_version; 87 | IF (_tables_version<_required_version) THEN 88 | RAISE EXCEPTION 'Current tables version % is less than minimally required % for % code version, please update tables structure', _tables_version, _required_version, index_watch.version(); 89 | END IF; 90 | END; 91 | $BODY$ 92 | LANGUAGE plpgsql; 93 | 94 | 95 | 96 | CREATE OR REPLACE FUNCTION index_watch.check_update_structure_version() 97 | RETURNS VOID AS 98 | $BODY$ 99 | DECLARE 100 | _tables_version INTEGER; 101 | _required_version INTEGER := 8; 102 | BEGIN 103 | SELECT version INTO STRICT _tables_version FROM index_watch.tables_version; 104 | WHILE (_tables_version<_required_version) LOOP 105 | EXECUTE 'SELECT index_watch._structure_version_'||_tables_version||'_'||_tables_version+1||'()'; 106 | _tables_version := _tables_version+1; 107 | END LOOP; 108 | RETURN; 109 | END; 110 | $BODY$ 111 | LANGUAGE plpgsql; 112 | 113 | 114 | --update table structure version from 1 to 2 115 | CREATE OR REPLACE FUNCTION index_watch._structure_version_1_2() 116 | RETURNS VOID AS 117 | $BODY$ 118 | BEGIN 119 | CREATE VIEW index_watch.history AS 120 | SELECT date_trunc('second', entry_timestamp)::timestamp AS ts, 121 | datname AS db, schemaname AS schema, relname AS table, 122 | indexrelname AS index, indexsize_before AS size_before, indexsize_after AS size_after, 123 | (indexsize_before::float/indexsize_after)::numeric(12,2) AS ratio, 124 | estimated_tuples AS tuples, date_trunc('seconds', reindex_duration) AS duration 125 | FROM index_watch.reindex_history ORDER BY id DESC; 126 | UPDATE index_watch.tables_version SET version=2; 127 | RETURN; 128 | END; 129 | $BODY$ 130 | LANGUAGE plpgsql; 131 | 132 | 133 | --update table structure version from 2 to 3 134 | CREATE OR REPLACE FUNCTION index_watch._structure_version_2_3() 135 | RETURNS VOID AS 136 | $BODY$ 137 | BEGIN 138 | CREATE TABLE IF NOT EXISTS index_watch.index_current_state 139 | ( 140 | id bigserial primary key, 141 | mtime timestamptz not null default now(), 142 | datname name not null, 143 | schemaname name not null, 144 | relname name not null, 145 | indexrelname name not null, 146 | indexsize BIGINT not null, 147 | estimated_tuples BIGINT not null, 148 | best_ratio REAL 149 | ); 150 | CREATE UNIQUE INDEX index_current_state_index on index_watch.index_current_state(datname, schemaname, relname, indexrelname); 151 | 152 | UPDATE index_watch.config SET value='128kB' 153 | WHERE key='minimum_reliable_index_size' AND pg_size_bytes(value)=coalesce(_last_reindex_values.entry_timestamp, '-INFINITY'::timestamp) 173 | ), 174 | _best_values AS ( 175 | --only valid best if reindex entry exists 176 | SELECT 177 | DISTINCT ON (datname, schemaname, relname, indexrelname) 178 | _all_history_since_reindex.*, 179 | _all_history_since_reindex.indexsize::real/_all_history_since_reindex.estimated_tuples::real as best_ratio 180 | FROM _all_history_since_reindex 181 | JOIN _last_reindex_values USING (datname, schemaname, relname, indexrelname) 182 | WHERE _all_history_since_reindex.indexsize > pg_size_bytes('128kB') 183 | ORDER BY datname, schemaname, relname, indexrelname, _all_history_since_reindex.indexsize::real/_all_history_since_reindex.estimated_tuples::real 184 | ), 185 | _current_state AS ( 186 | SELECT 187 | DISTINCT ON (datname, schemaname, relname, indexrelname) 188 | _all_history_since_reindex.* 189 | FROM _all_history_since_reindex 190 | ORDER BY datname, schemaname, relname, indexrelname, entry_timestamp DESC 191 | ) 192 | INSERT INTO index_watch.index_current_state 193 | (mtime, datname, schemaname, relname, indexrelname, indexsize, estimated_tuples, best_ratio) 194 | SELECT c.entry_timestamp, c.datname, c.schemaname, c.relname, c.indexrelname, c.indexsize, c.estimated_tuples, best_ratio 195 | FROM _current_state c JOIN _best_values USING (datname, schemaname, relname, indexrelname); 196 | DROP TABLE index_watch.index_history; 197 | UPDATE index_watch.tables_version SET version=3; 198 | RETURN; 199 | END; 200 | $BODY$ 201 | LANGUAGE plpgsql; 202 | 203 | 204 | -- set dblink connection if not exists 205 | CREATE OR REPLACE FUNCTION index_watch._dblink_connect_if_not(_datname NAME) RETURNS VOID AS 206 | $BODY$ 207 | BEGIN 208 | IF _datname = ANY(dblink_get_connections()) IS NOT TRUE THEN 209 | PERFORM dblink_connect(_datname, 'port='||current_setting('port')||$$ dbname='$$||_datname||$$'$$); 210 | END IF; 211 | RETURN; 212 | END; 213 | $BODY$ 214 | LANGUAGE plpgsql; 215 | 216 | 217 | 218 | CREATE OR REPLACE FUNCTION index_watch._remote_get_indexes_indexrelid(_datname name) 219 | RETURNS TABLE(datname name, schemaname name, relname name, indexrelname name, indexrelid OID) 220 | AS 221 | $BODY$ 222 | DECLARE 223 | _use_toast_tables text; 224 | BEGIN 225 | IF index_watch._check_pg_version_bugfixed() THEN _use_toast_tables := 'True'; 226 | ELSE _use_toast_tables := 'False'; 227 | END IF; 228 | RETURN QUERY SELECT 229 | _datname, _res.schemaname, _res.relname, _res.indexrelname, _res.indexrelid 230 | FROM 231 | dblink(_datname, 232 | format( 233 | $SQL$ 234 | SELECT 235 | n.nspname AS schemaname 236 | , c.relname 237 | , i.relname AS indexrelname 238 | , x.indexrelid 239 | FROM pg_index x 240 | JOIN pg_catalog.pg_class c ON c.oid = x.indrelid 241 | JOIN pg_catalog.pg_class i ON i.oid = x.indexrelid 242 | JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace 243 | JOIN pg_catalog.pg_am a ON a.oid = i.relam 244 | --toast indexes info 245 | LEFT JOIN pg_catalog.pg_class c1 ON c1.reltoastrelid = c.oid AND n.nspname = 'pg_toast' 246 | LEFT JOIN pg_catalog.pg_namespace n1 ON c1.relnamespace = n1.oid 247 | 248 | WHERE 249 | TRUE 250 | --limit reindex for indexes on tables/mviews/toast 251 | --AND c.relkind = ANY (ARRAY['r'::"char", 't'::"char", 'm'::"char"]) 252 | --limit reindex for indexes on tables/mviews (skip topast until bugfix of BUG #17268) 253 | AND ( (c.relkind = ANY (ARRAY['r'::"char", 'm'::"char"])) OR 254 | ( (c.relkind = 't'::"char") AND %s ) 255 | ) 256 | --ignore exclusion constraints 257 | AND NOT EXISTS (SELECT FROM pg_constraint WHERE pg_constraint.conindid=i.oid and pg_constraint.contype='x') 258 | --ignore indexes for system tables and index_watch own tables 259 | AND n.nspname NOT IN ('pg_catalog', 'information_schema', 'index_watch') 260 | --ignore indexes on toast tables of system tables and index_watch own tables 261 | AND (n1.nspname IS NULL OR n1.nspname NOT IN ('pg_catalog', 'information_schema', 'index_watch')) 262 | --skip BRIN indexes... please see bug BUG #17205 https://www.postgresql.org/message-id/flat/17205-42b1d8f131f0cf97%%40postgresql.org 263 | AND a.amname NOT IN ('brin') AND x.indislive IS TRUE 264 | --skip indexes on temp relations 265 | AND c.relpersistence<>'t' 266 | --debug only 267 | --ORDER by 1,2,3 268 | $SQL$, _use_toast_tables) 269 | ) 270 | AS _res(schemaname name, relname name, indexrelname name, indexrelid OID) 271 | ; 272 | END; 273 | $BODY$ 274 | LANGUAGE plpgsql; 275 | 276 | 277 | 278 | --update table structure version from 3 to 4 279 | CREATE OR REPLACE FUNCTION index_watch._structure_version_3_4() 280 | RETURNS VOID AS 281 | $BODY$ 282 | DECLARE 283 | _datname NAME; 284 | BEGIN 285 | ALTER TABLE index_watch.reindex_history 286 | ADD COLUMN indexrelid OID; 287 | CREATE INDEX reindex_history_oid_index on index_watch.reindex_history(datname, indexrelid); 288 | 289 | ALTER TABLE index_watch.index_current_state 290 | ADD COLUMN indexrelid OID; 291 | CREATE UNIQUE INDEX index_current_state_oid_index on index_watch.index_current_state(datname, indexrelid); 292 | DROP INDEX IF EXISTS index_watch.index_current_state_index; 293 | CREATE INDEX index_current_state_index on index_watch.index_current_state(datname, schemaname, relname, indexrelname); 294 | 295 | -- add indexrelid values into index_current_state 296 | FOR _datname IN 297 | SELECT DISTINCT datname FROM index_watch.index_current_state 298 | ORDER BY datname 299 | LOOP 300 | PERFORM index_watch._dblink_connect_if_not(_datname); 301 | --update current state of ALL indexes in target database 302 | WITH _actual_indexes AS ( 303 | SELECT schemaname, relname, indexrelname, indexrelid 304 | FROM index_watch._remote_get_indexes_indexrelid(_datname) 305 | ) 306 | UPDATE index_watch.index_current_state AS i 307 | SET indexrelid=_actual_indexes.indexrelid 308 | FROM _actual_indexes 309 | WHERE 310 | i.schemaname=_actual_indexes.schemaname 311 | AND i.relname=_actual_indexes.relname 312 | AND i.indexrelname=_actual_indexes.indexrelname 313 | AND i.datname=_datname; 314 | PERFORM dblink_disconnect(_datname); 315 | END LOOP; 316 | DELETE FROM index_watch.index_current_state WHERE indexrelid IS NULL; 317 | ALTER TABLE index_watch.index_current_state ALTER indexrelid SET NOT NULL; 318 | UPDATE index_watch.tables_version SET version=4; 319 | RETURN; 320 | END; 321 | $BODY$ 322 | LANGUAGE plpgsql; 323 | 324 | 325 | --update table structure version from 4 to 5 326 | CREATE OR REPLACE FUNCTION index_watch._structure_version_4_5() 327 | RETURNS VOID AS 328 | $BODY$ 329 | DECLARE 330 | _datname NAME; 331 | BEGIN 332 | ALTER TABLE index_watch.reindex_history 333 | ADD COLUMN datid OID; 334 | DROP INDEX IF EXISTS index_watch.reindex_history_oid_index; 335 | CREATE INDEX reindex_history_oid_index on index_watch.reindex_history(datid, indexrelid); 336 | 337 | ALTER TABLE index_watch.index_current_state 338 | ADD COLUMN datid OID; 339 | DROP INDEX IF EXISTS index_watch.index_current_state_oid_index; 340 | CREATE UNIQUE INDEX index_current_state_oid_index on index_watch.index_current_state(datid, indexrelid); 341 | 342 | -- add datid values into index_current_state 343 | UPDATE index_watch.index_current_state AS i 344 | SET datid=p.oid 345 | FROM pg_database p 346 | WHERE i.datname=p.datname; 347 | DELETE FROM index_watch.index_current_state WHERE datid IS NULL; 348 | ALTER TABLE index_watch.index_current_state ALTER datid SET NOT NULL; 349 | UPDATE index_watch.tables_version SET version=5; 350 | RETURN; 351 | END; 352 | $BODY$ 353 | LANGUAGE plpgsql; 354 | 355 | 356 | --update table structure version from 5 to 6 357 | CREATE OR REPLACE FUNCTION index_watch._structure_version_5_6() 358 | RETURNS VOID AS 359 | $BODY$ 360 | BEGIN 361 | ALTER TABLE index_watch.index_current_state 362 | ADD COLUMN indisvalid BOOLEAN not null DEFAULT TRUE; 363 | UPDATE index_watch.tables_version SET version=6; 364 | RETURN; 365 | END; 366 | $BODY$ 367 | LANGUAGE plpgsql; 368 | 369 | 370 | 371 | --update table structure version from 6 to 7 372 | CREATE OR REPLACE FUNCTION index_watch._structure_version_6_7() 373 | RETURNS VOID AS 374 | $BODY$ 375 | BEGIN 376 | DROP VIEW IF EXISTS index_watch.history; 377 | CREATE VIEW index_watch.history AS 378 | SELECT date_trunc('second', entry_timestamp)::timestamp AS ts, 379 | datname AS db, schemaname AS schema, relname AS table, 380 | indexrelname AS index, pg_size_pretty(indexsize_before) AS size_before, 381 | pg_size_pretty(indexsize_after) AS size_after, 382 | (indexsize_before::float/indexsize_after)::numeric(12,2) AS ratio, 383 | pg_size_pretty(estimated_tuples) AS tuples, date_trunc('seconds', reindex_duration) AS duration 384 | FROM index_watch.reindex_history ORDER BY id DESC; 385 | 386 | UPDATE index_watch.tables_version SET version=7; 387 | RETURN; 388 | END; 389 | $BODY$ 390 | LANGUAGE plpgsql; 391 | 392 | 393 | --update table structure version from 7 to 8 394 | CREATE OR REPLACE FUNCTION index_watch._structure_version_7_8() 395 | RETURNS VOID AS 396 | $BODY$ 397 | BEGIN 398 | CREATE TABLE IF NOT EXISTS index_watch.current_processed_index 399 | ( 400 | id bigserial primary key, 401 | mtime timestamptz not null default now(), 402 | datname name not null, 403 | schemaname name not null, 404 | relname name not null, 405 | indexrelname name not null 406 | ); 407 | 408 | UPDATE index_watch.tables_version SET version=8; 409 | RETURN; 410 | END; 411 | $BODY$ 412 | LANGUAGE plpgsql; 413 | 414 | 415 | --convert patterns from psql format to like format 416 | CREATE OR REPLACE FUNCTION index_watch._pattern_convert(_var text) 417 | RETURNS TEXT AS 418 | $BODY$ 419 | BEGIN 420 | --replace * with .* 421 | _var := replace(_var, '*', '.*'); 422 | --replace ? with . 423 | _var := replace(_var, '?', '.'); 424 | 425 | RETURN '^('||_var||')$'; 426 | END; 427 | $BODY$ 428 | LANGUAGE plpgsql STRICT IMMUTABLE; 429 | 430 | 431 | CREATE OR REPLACE FUNCTION index_watch.get_setting(_datname text, _schemaname text, _relname text, _indexrelname text, _key TEXT) 432 | RETURNS TEXT AS 433 | $BODY$ 434 | DECLARE 435 | _value TEXT; 436 | BEGIN 437 | PERFORM index_watch._check_structure_version(); 438 | --RAISE NOTICE 'DEBUG: |%|%|%|%|', _datname, _schemaname, _relname, _indexrelname; 439 | SELECT _t.value INTO _value FROM ( 440 | --per index setting 441 | SELECT 1 AS priority, value FROM index_watch.config WHERE 442 | _key=config.key 443 | AND (_datname OPERATOR(pg_catalog.~) index_watch._pattern_convert(config.datname)) 444 | AND (_schemaname OPERATOR(pg_catalog.~) index_watch._pattern_convert(config.schemaname)) 445 | AND (_relname OPERATOR(pg_catalog.~) index_watch._pattern_convert(config.relname)) 446 | AND (_indexrelname OPERATOR(pg_catalog.~) index_watch._pattern_convert(config.indexrelname)) 447 | AND config.indexrelname IS NOT NULL 448 | AND TRUE 449 | UNION ALL 450 | --per table setting 451 | SELECT 2 AS priority, value FROM index_watch.config WHERE 452 | _key=config.key 453 | AND (_datname OPERATOR(pg_catalog.~) index_watch._pattern_convert(config.datname)) 454 | AND (_schemaname OPERATOR(pg_catalog.~) index_watch._pattern_convert(config.schemaname)) 455 | AND (_relname OPERATOR(pg_catalog.~) index_watch._pattern_convert(config.relname)) 456 | AND config.relname IS NOT NULL 457 | AND config.indexrelname IS NULL 458 | UNION ALL 459 | --per schema setting 460 | SELECT 3 AS priority, value FROM index_watch.config WHERE 461 | _key=config.key 462 | AND (_datname OPERATOR(pg_catalog.~) index_watch._pattern_convert(config.datname)) 463 | AND (_schemaname OPERATOR(pg_catalog.~) index_watch._pattern_convert(config.schemaname)) 464 | AND config.schemaname IS NOT NULL 465 | AND config.relname IS NULL 466 | UNION ALL 467 | --per database setting 468 | SELECT 4 AS priority, value FROM index_watch.config WHERE 469 | _key=config.key 470 | AND (_datname OPERATOR(pg_catalog.~) index_watch._pattern_convert(config.datname)) 471 | AND config.datname IS NOT NULL 472 | AND config.schemaname IS NULL 473 | UNION ALL 474 | --global setting 475 | SELECT 5 AS priority, value FROM index_watch.config WHERE 476 | _key=config.key 477 | AND config.datname IS NULL 478 | ) AS _t 479 | WHERE value IS NOT NULL 480 | ORDER BY priority 481 | LIMIT 1; 482 | RETURN _value; 483 | END; 484 | $BODY$ 485 | LANGUAGE plpgsql STABLE; 486 | 487 | 488 | CREATE OR REPLACE FUNCTION index_watch.set_or_replace_setting(_datname text, _schemaname text, _relname text, _indexrelname text, _key TEXT, _value text, _comment text) 489 | RETURNS VOID AS 490 | $BODY$ 491 | BEGIN 492 | PERFORM index_watch._check_structure_version(); 493 | IF _datname IS NULL THEN 494 | INSERT INTO index_watch.config (datname, schemaname, relname, indexrelname, key, value, comment) 495 | VALUES (_datname, _schemaname, _relname, _indexrelname, _key, _value, _comment) 496 | ON CONFLICT (key) WHERE datname IS NULL DO UPDATE SET value=EXCLUDED.value, comment=EXCLUDED.comment; 497 | ELSIF _schemaname IS NULL THEN 498 | INSERT INTO index_watch.config (datname, schemaname, relname, indexrelname, key, value, comment) 499 | VALUES (_datname, _schemaname, _relname, _indexrelname, _key, _value, _comment) 500 | ON CONFLICT (key, datname) WHERE schemaname IS NULL DO UPDATE SET value=EXCLUDED.value, comment=EXCLUDED.comment; 501 | ELSIF _relname IS NULL THEN 502 | INSERT INTO index_watch.config (datname, schemaname, relname, indexrelname, key, value, comment) 503 | VALUES (_datname, _schemaname, _relname, _indexrelname, _key, _value, _comment) 504 | ON CONFLICT (key, datname, schemaname) WHERE relname IS NULL DO UPDATE SET value=EXCLUDED.value, comment=EXCLUDED.comment; 505 | ELSIF _indexrelname IS NULL THEN 506 | INSERT INTO index_watch.config (datname, schemaname, relname, indexrelname, key, value, comment) 507 | VALUES (_datname, _schemaname, _relname, _indexrelname, _key, _value, _comment) 508 | ON CONFLICT (key, datname, schemaname, relname) WHERE indexrelname IS NULL DO UPDATE SET value=EXCLUDED.value, comment=EXCLUDED.comment; 509 | ELSE 510 | INSERT INTO index_watch.config (datname, schemaname, relname, indexrelname, key, value, comment) 511 | VALUES (_datname, _schemaname, _relname, _indexrelname, _key, _value, _comment) 512 | ON CONFLICT (key, datname, schemaname, relname, indexrelname) DO UPDATE SET value=EXCLUDED.value, comment=EXCLUDED.comment; 513 | END IF; 514 | RETURN; 515 | END; 516 | $BODY$ 517 | LANGUAGE plpgsql; 518 | 519 | 520 | DROP FUNCTION IF EXISTS index_watch._remote_get_indexes_info(name,name,name,name); 521 | CREATE OR REPLACE FUNCTION index_watch._remote_get_indexes_info(_datname name, _schemaname name, _relname name, _indexrelname name) 522 | RETURNS TABLE(datid OID, indexrelid OID, datname name, schemaname name, relname name, indexrelname name, indisvalid BOOLEAN, indexsize BIGINT, estimated_tuples BIGINT) 523 | AS 524 | $BODY$ 525 | DECLARE 526 | _use_toast_tables text; 527 | BEGIN 528 | IF index_watch._check_pg_version_bugfixed() THEN _use_toast_tables := 'True'; 529 | ELSE _use_toast_tables := 'False'; 530 | END IF; 531 | RETURN QUERY SELECT 532 | d.oid as datid, _res.indexrelid, _datname, _res.schemaname, _res.relname, _res.indexrelname, _res.indisvalid, _res.indexsize 533 | -- zero tuples clamp up 1 tuple (or bloat estimates will be infinity with all division by zero fun in multiple places) 534 | , greatest (1, indexreltuples) 535 | -- don't do relsize/relpage correction, that logic found to be way too smart for his own good 536 | -- greatest (1, (CASE WHEN relpages=0 THEN indexreltuples ELSE relsize*indexreltuples/(relpages*current_setting('block_size')) END AS estimated_tuples)) 537 | FROM 538 | dblink(_datname, 539 | format($SQL$ 540 | SELECT 541 | x.indexrelid 542 | , n.nspname AS schemaname 543 | , c.relname 544 | , i.relname AS indexrelname 545 | , x.indisvalid 546 | , i.reltuples::BIGINT AS indexreltuples 547 | , pg_catalog.pg_relation_size(i.oid)::BIGINT AS indexsize 548 | --debug only 549 | --, pg_namespace.nspname 550 | --, c3.relname, 551 | --, am.amname 552 | FROM pg_index x 553 | JOIN pg_catalog.pg_class c ON c.oid = x.indrelid 554 | JOIN pg_catalog.pg_class i ON i.oid = x.indexrelid 555 | JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace 556 | JOIN pg_catalog.pg_am a ON a.oid = i.relam 557 | --toast indexes info 558 | LEFT JOIN pg_catalog.pg_class c1 ON c1.reltoastrelid = c.oid AND n.nspname = 'pg_toast' 559 | LEFT JOIN pg_catalog.pg_namespace n1 ON c1.relnamespace = n1.oid 560 | 561 | WHERE TRUE 562 | --limit reindex for indexes on tables/mviews/toast 563 | --AND c.relkind = ANY (ARRAY['r'::"char", 't'::"char", 'm'::"char"]) 564 | --limit reindex for indexes on tables/mviews (skip topast until bugfix of BUG #17268) 565 | AND ( (c.relkind = ANY (ARRAY['r'::"char", 'm'::"char"])) OR 566 | ( (c.relkind = 't'::"char") AND %s ) 567 | ) 568 | --ignore exclusion constraints 569 | AND NOT EXISTS (SELECT FROM pg_constraint WHERE pg_constraint.conindid=i.oid and pg_constraint.contype='x') 570 | --ignore indexes for system tables and index_watch own tables 571 | AND n.nspname NOT IN ('pg_catalog', 'information_schema', 'index_watch') 572 | --ignore indexes on toast tables of system tables and index_watch own tables 573 | AND (n1.nspname IS NULL OR n1.nspname NOT IN ('pg_catalog', 'information_schema', 'index_watch')) 574 | --skip BRIN indexes... please see bug BUG #17205 https://www.postgresql.org/message-id/flat/17205-42b1d8f131f0cf97%%40postgresql.org 575 | AND a.amname NOT IN ('brin') AND x.indislive IS TRUE 576 | --skip indexes on temp relations 577 | AND c.relpersistence<>'t' 578 | --debug only 579 | --ORDER by 1,2,3 580 | $SQL$, _use_toast_tables) 581 | ) 582 | AS _res(indexrelid OID, schemaname name, relname name, indexrelname name, indisvalid BOOLEAN, indexreltuples BIGINT, indexsize BIGINT), 583 | pg_database AS d 584 | WHERE 585 | d.datname=_datname 586 | AND 587 | (_schemaname IS NULL OR _res.schemaname=_schemaname) 588 | AND 589 | (_relname IS NULL OR _res.relname=_relname) 590 | AND 591 | (_indexrelname IS NULL OR _res.indexrelname=_indexrelname) 592 | ; 593 | END; 594 | $BODY$ 595 | LANGUAGE plpgsql; 596 | 597 | 598 | DROP FUNCTION IF EXISTS index_watch._record_indexes_info(name, name, name, name); 599 | CREATE OR REPLACE FUNCTION index_watch._record_indexes_info(_datname name, _schemaname name, _relname name, _indexrelname name, _force_populate boolean DEFAULT false) 600 | RETURNS VOID 601 | AS 602 | $BODY$ 603 | DECLARE 604 | index_info RECORD; 605 | BEGIN 606 | --merge index data fetched from the database and index_current_state 607 | --now keep info about all potentially interesting indexes (even small ones) 608 | --we can do it now because we keep exactly one entry in index_current_state per index (without history) 609 | WITH _actual_indexes AS ( 610 | SELECT datid, indexrelid, datname, schemaname, relname, indexrelname, indisvalid, indexsize, estimated_tuples 611 | FROM index_watch._remote_get_indexes_info(_datname, _schemaname, _relname, _indexrelname) 612 | ), 613 | _old_indexes AS ( 614 | DELETE FROM index_watch.index_current_state AS i 615 | WHERE NOT EXISTS ( 616 | SELECT FROM _actual_indexes 617 | WHERE 618 | i.datid=_actual_indexes.datid 619 | AND i.indexrelid=_actual_indexes.indexrelid 620 | ) 621 | AND i.datname=_datname 622 | AND (_schemaname IS NULL OR i.schemaname=_schemaname) 623 | AND (_relname IS NULL OR i.relname=_relname) 624 | AND (_indexrelname IS NULL OR i.indexrelname=_indexrelname) 625 | ) 626 | --todo: do something with ugly code duplication in index_watch._reindex_index and index_watch._record_indexes_info 627 | INSERT INTO index_watch.index_current_state AS i 628 | (datid, indexrelid, datname, schemaname, relname, indexrelname, indisvalid, indexsize, estimated_tuples, best_ratio) 629 | SELECT datid, indexrelid, datname, schemaname, relname, indexrelname, indisvalid, indexsize, estimated_tuples, 630 | CASE 631 | --_force_populate=TRUE set (or write) best ratio to current ratio (except the case when index too small to be realiable estimated) 632 | WHEN (_force_populate AND indexsize > pg_size_bytes(index_watch.get_setting(datname, schemaname, relname, indexrelname, 'minimum_reliable_index_size'))) 633 | THEN indexsize::real/estimated_tuples::real 634 | --best_ratio estimation are NULL for the NEW index entries because we don't have any bloat information for it (default behavior) 635 | ELSE 636 | NULL 637 | END 638 | AS best_ratio 639 | FROM _actual_indexes 640 | ON CONFLICT (datid,indexrelid) 641 | DO UPDATE SET 642 | mtime=now(), 643 | datname=EXCLUDED.datname, 644 | schemaname=EXCLUDED.schemaname, 645 | relname=EXCLUDED.relname, 646 | indexrelname=EXCLUDED.indexrelname, 647 | indisvalid=EXCLUDED.indisvalid, 648 | indexsize=EXCLUDED.indexsize, 649 | estimated_tuples=EXCLUDED.estimated_tuples, 650 | best_ratio= 651 | CASE 652 | --_force_populate=TRUE set (or write) best ratio to current ratio (except the case when index too small to be realiable estimated) 653 | WHEN (_force_populate AND EXCLUDED.indexsize > pg_size_bytes(index_watch.get_setting(EXCLUDED.datname, EXCLUDED.schemaname, EXCLUDED.relname, EXCLUDED.indexrelname, 'minimum_reliable_index_size'))) 654 | THEN EXCLUDED.indexsize::real/EXCLUDED.estimated_tuples::real 655 | --if the new index size less than minimum_reliable_index_size - we cannot use it's size and tuples as reliable gauge for the best_ratio 656 | --so keep old best_ratio value instead as best guess 657 | WHEN (EXCLUDED.indexsize < pg_size_bytes(index_watch.get_setting(EXCLUDED.datname, EXCLUDED.schemaname, EXCLUDED.relname, EXCLUDED.indexrelname, 'minimum_reliable_index_size'))) 658 | THEN i.best_ratio 659 | --do not overrrid NULL best ratio (we don't have any reliable ratio info at this stage) 660 | WHEN (i.best_ratio IS NULL) 661 | THEN NULL 662 | -- set best_value as least from current value and new one 663 | ELSE 664 | least(i.best_ratio, EXCLUDED.indexsize::real/EXCLUDED.estimated_tuples::real) 665 | END; 666 | 667 | --tell about not valid indexes 668 | FOR index_info IN 669 | SELECT indexrelname, relname, schemaname, datname FROM index_watch.index_current_state 670 | WHERE indisvalid IS FALSE 671 | AND datname=_datname 672 | AND (_schemaname IS NULL OR schemaname=_schemaname) 673 | AND (_relname IS NULL OR relname=_relname) 674 | AND (_indexrelname IS NULL OR indexrelname=_indexrelname) 675 | LOOP 676 | RAISE WARNING 'Not valid index % on %.% found in %.', 677 | index_info.indexrelname, index_info.schemaname, index_info.relname, index_info.datname; 678 | END LOOP; 679 | 680 | END; 681 | $BODY$ 682 | LANGUAGE plpgsql; 683 | 684 | 685 | 686 | CREATE OR REPLACE FUNCTION index_watch._cleanup_old_records() RETURNS VOID AS 687 | $BODY$ 688 | BEGIN 689 | --TODO replace with fast distinct implementation 690 | WITH 691 | rels AS MATERIALIZED (SELECT DISTINCT datname, schemaname, relname, indexrelname FROM index_watch.reindex_history), 692 | age_limit AS MATERIALIZED (SELECT *, now()-index_watch.get_setting(datname,schemaname,relname,indexrelname, 'reindex_history_retention_period')::interval AS max_age FROM rels) 693 | DELETE FROM index_watch.reindex_history 694 | USING age_limit 695 | WHERE 696 | reindex_history.datname=age_limit.datname 697 | AND reindex_history.schemaname=age_limit.schemaname 698 | AND reindex_history.relname=age_limit.relname 699 | AND reindex_history.indexrelname=age_limit.indexrelname 700 | AND reindex_history.entry_timestamp= pg_size_bytes(index_watch.get_setting(datname, schemaname, relname, indexrelname, 'index_size_threshold')) 858 | --skip indexes set to skip 859 | AND index_watch.get_setting(datname, schemaname, relname, indexrelname, 'skip')::boolean IS DISTINCT FROM TRUE 860 | -- AND index_watch.get_setting (for future configurability) 861 | AND ( 862 | estimated_bloat IS NULL 863 | OR estimated_bloat >= index_watch.get_setting(datname, schemaname, relname, indexrelname, 'index_rebuild_scale_factor')::float 864 | ) 865 | ) 866 | ) 867 | LOOP 868 | INSERT INTO index_watch.current_processed_index( 869 | datname, 870 | schemaname, 871 | relname, 872 | indexrelname 873 | ) 874 | VALUES ( 875 | _index.datname, 876 | _index.schemaname, 877 | _index.relname, 878 | _index.indexrelname 879 | ); 880 | COMMIT; 881 | PERFORM index_watch._reindex_index(_index.datname, _index.schemaname, _index.relname, _index.indexrelname); 882 | COMMIT; 883 | DELETE FROM index_watch.current_processed_index 884 | WHERE 885 | datname=_index.datname AND 886 | schemaname=_index.schemaname AND 887 | relname=_index.relname AND 888 | indexrelname=_index.indexrelname; 889 | COMMIT; 890 | END LOOP; 891 | RETURN; 892 | END; 893 | $BODY$ 894 | LANGUAGE plpgsql; 895 | 896 | 897 | --user callable shell over index_watch._record_indexes_info(... _force_populate=>TRUE) 898 | --use to populate index bloa info from current state without reindexing 899 | CREATE OR REPLACE FUNCTION index_watch.do_force_populate_index_stats(_datname name, _schemaname name, _relname name, _indexrelname name) 900 | RETURNS VOID 901 | AS 902 | $BODY$ 903 | BEGIN 904 | PERFORM index_watch._check_structure_version(); 905 | PERFORM index_watch._dblink_connect_if_not(_datname); 906 | PERFORM index_watch._record_indexes_info(_datname, _schemaname, _relname, _indexrelname, _force_populate=>TRUE); 907 | RETURN; 908 | END; 909 | $BODY$ 910 | LANGUAGE plpgsql; 911 | 912 | 913 | CREATE OR REPLACE FUNCTION index_watch._check_lock() 914 | RETURNS bigint AS 915 | $BODY$ 916 | DECLARE 917 | _id bigint; 918 | _is_not_running boolean; 919 | BEGIN 920 | SELECT oid FROM pg_namespace WHERE nspname='index_watch' INTO _id; 921 | SELECT pg_try_advisory_lock(_id) INTO _is_not_running; 922 | IF NOT _is_not_running THEN 923 | RAISE 'The previous launch of the index_watch.periodic is still running.'; 924 | END IF; 925 | RETURN _id; 926 | END; 927 | $BODY$ 928 | LANGUAGE plpgsql; 929 | 930 | 931 | CREATE OR REPLACE PROCEDURE index_watch._cleanup_our_not_valid_indexes() AS 932 | $BODY$ 933 | DECLARE 934 | _index RECORD; 935 | BEGIN 936 | FOR _index IN 937 | SELECT datname, schemaname, relname, indexrelname FROM 938 | index_watch.current_processed_index 939 | LOOP 940 | PERFORM index_watch._dblink_connect_if_not(_index.datname); 941 | IF EXISTS (SELECT FROM dblink(_index.datname, 942 | format( 943 | $SQL$ 944 | SELECT x.indexrelid 945 | FROM pg_index x 946 | JOIN pg_catalog.pg_class c ON c.oid = x.indrelid 947 | JOIN pg_catalog.pg_class i ON i.oid = x.indexrelid 948 | JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace 949 | 950 | WHERE 951 | n.nspname = '%1$s' 952 | AND c.relname = '%2$s' 953 | AND i.relname = '%3$s_ccnew' 954 | AND x.indisvalid IS FALSE 955 | $SQL$ 956 | , _index.schemaname, _index.relname, _index.indexrelname)) AS _res(indexrelid OID) ) 957 | THEN 958 | IF NOT EXISTS (SELECT FROM dblink(_index.datname, 959 | format( 960 | $SQL$ 961 | SELECT x.indexrelid 962 | FROM pg_index x 963 | JOIN pg_catalog.pg_class c ON c.oid = x.indrelid 964 | JOIN pg_catalog.pg_class i ON i.oid = x.indexrelid 965 | JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace 966 | 967 | WHERE 968 | n.nspname = '%1$s' 969 | AND c.relname = '%2$s' 970 | AND i.relname = '%3$s' 971 | $SQL$ 972 | , _index.schemaname, _index.relname, _index.indexrelname)) AS _res(indexrelid OID) ) 973 | THEN 974 | RAISE WARNING 'The invalid index %.%_ccnew exists, but no original index %.% was found in database %', _index.schemaname, _index.indexrelname, _index.schemaname, _index.indexrelname, _index.datname; 975 | END IF; 976 | PERFORM dblink(_index.datname, format('DROP INDEX CONCURRENTLY %I.%I_ccnew', _index.schemaname, _index.indexrelname)); 977 | RAISE WARNING 'The invalid index %.%_ccnew was dropped in database %', _index.schemaname, _index.indexrelname, _index.datname; 978 | END IF; 979 | DELETE FROM index_watch.current_processed_index 980 | WHERE 981 | datname=_index.datname AND 982 | schemaname=_index.schemaname AND 983 | relname=_index.relname AND 984 | indexrelname=_index.indexrelname; 985 | COMMIT; 986 | END LOOP; 987 | END; 988 | $BODY$ 989 | LANGUAGE plpgsql; 990 | 991 | 992 | DROP PROCEDURE IF EXISTS index_watch.periodic(BOOLEAN); 993 | CREATE OR REPLACE PROCEDURE index_watch.periodic(real_run BOOLEAN DEFAULT FALSE, force BOOLEAN DEFAULT FALSE) AS 994 | $BODY$ 995 | DECLARE 996 | _datname NAME; 997 | _schemaname NAME; 998 | _relname NAME; 999 | _indexrelname NAME; 1000 | _id bigint; 1001 | BEGIN 1002 | IF NOT index_watch._check_pg14_version_bugfixed() 1003 | THEN 1004 | RAISE 'The database version % affected by PostgreSQL bug BUG #17485 which make use pg_index_watch unsafe, please update to latest minor release. For additional info please see: 1005 | https://www.postgresql.org/message-id/202205251144.6t4urostzc3s@alvherre.pgsql', 1006 | current_setting('server_version'); 1007 | END IF; 1008 | IF NOT index_watch._check_pg_version_bugfixed() 1009 | THEN 1010 | RAISE WARNING 'The database version % affected by PostgreSQL bugs which make use pg_index_watch potentially unsafe, please update to latest minor release. For additional info please see: 1011 | https://www.postgresql.org/message-id/E1mumI4-0001Zp-PB@gemulon.postgresql.org 1012 | and 1013 | https://www.postgresql.org/message-id/E1n8C7O-00066j-Q5@gemulon.postgresql.org', 1014 | current_setting('server_version'); 1015 | END IF; 1016 | 1017 | SELECT index_watch._check_lock() INTO _id; 1018 | PERFORM index_watch.check_update_structure_version(); 1019 | COMMIT; 1020 | PERFORM index_watch._cleanup_old_records(); 1021 | COMMIT; 1022 | CALL index_watch._cleanup_our_not_valid_indexes(); 1023 | COMMIT; 1024 | 1025 | FOR _datname IN 1026 | SELECT datname FROM pg_database 1027 | WHERE 1028 | NOT datistemplate 1029 | AND datallowconn 1030 | AND datname<>current_database() 1031 | AND index_watch.get_setting(datname, NULL, NULL, NULL, 'skip')::boolean IS DISTINCT FROM TRUE 1032 | ORDER BY datname 1033 | LOOP 1034 | PERFORM index_watch._dblink_connect_if_not(_datname); 1035 | --update current state of ALL indexes in target database 1036 | PERFORM index_watch._record_indexes_info(_datname, NULL, NULL, NULL); 1037 | COMMIT; 1038 | --if real_run isn't set - do nothing else 1039 | IF (real_run) THEN 1040 | CALL index_watch.do_reindex(_datname, NULL, NULL, NULL, force); 1041 | COMMIT; 1042 | END IF; 1043 | PERFORM dblink_disconnect(_datname); 1044 | END LOOP; 1045 | 1046 | PERFORM pg_advisory_unlock(_id); 1047 | END; 1048 | $BODY$ 1049 | LANGUAGE plpgsql; 1050 | 1051 | -------------------------------------------------------------------------------- /index_watch_tables.sql: -------------------------------------------------------------------------------- 1 | \set ON_ERROR_STOP 2 | 3 | DO $$ 4 | BEGIN 5 | IF (SELECT setting FROM pg_settings WHERE name='server_version_num')<'12' 6 | THEN 7 | RAISE 'This library works only for PostgreSQL 12 or higher!'; 8 | END IF; 9 | END; $$; 10 | 11 | 12 | 13 | CREATE SCHEMA IF NOT EXISTS index_watch; 14 | 15 | --history of performed REINDEX action 16 | CREATE TABLE index_watch.reindex_history 17 | ( 18 | id bigserial primary key, 19 | entry_timestamp timestamptz not null default now(), 20 | indexrelid OID, 21 | datid OID, 22 | datname name not null, 23 | schemaname name not null, 24 | relname name not null, 25 | indexrelname name not null, 26 | server_version_num integer not null default current_setting('server_version_num')::integer, 27 | indexsize_before BIGINT not null, 28 | indexsize_after BIGINT not null, 29 | estimated_tuples bigint not null, 30 | reindex_duration interval not null, 31 | analyze_duration interval not null 32 | ); 33 | CREATE INDEX reindex_history_oid_index on index_watch.reindex_history(datid, indexrelid); 34 | CREATE INDEX reindex_history_index on index_watch.reindex_history(datname, schemaname, relname, indexrelname); 35 | 36 | --history of index sizes (not really neccessary to keep all this data but very useful for future analyzis of bloat trends 37 | CREATE TABLE index_watch.index_current_state 38 | ( 39 | id bigserial primary key, 40 | mtime timestamptz not null default now(), 41 | indexrelid OID not null, 42 | datid OID not null, 43 | datname name not null, 44 | schemaname name not null, 45 | relname name not null, 46 | indexrelname name not null, 47 | indexsize BIGINT not null, 48 | indisvalid BOOLEAN not null DEFAULT TRUE, 49 | estimated_tuples BIGINT not null, 50 | best_ratio REAL 51 | ); 52 | CREATE UNIQUE INDEX index_current_state_oid_index on index_watch.index_current_state(datid, indexrelid); 53 | CREATE INDEX index_current_state_index on index_watch.index_current_state(datname, schemaname, relname, indexrelname); 54 | 55 | --settings table 56 | CREATE TABLE index_watch.config 57 | ( 58 | id bigserial primary key, 59 | datname name, 60 | schemaname name, 61 | relname name, 62 | indexrelname name, 63 | key text not null, 64 | value text, 65 | comment text 66 | ); 67 | CREATE UNIQUE INDEX config_u1 on index_watch.config(key) WHERE datname IS NULL; 68 | CREATE UNIQUE INDEX config_u2 on index_watch.config(key, datname) WHERE schemaname IS NULL; 69 | CREATE UNIQUE INDEX config_u3 on index_watch.config(key, datname, schemaname) WHERE relname IS NULL; 70 | CREATE UNIQUE INDEX config_u4 on index_watch.config(key, datname, schemaname, relname) WHERE indexrelname IS NULL; 71 | CREATE UNIQUE INDEX config_u5 on index_watch.config(key, datname, schemaname, relname, indexrelname); 72 | ALTER TABLE index_watch.config ADD CONSTRAINT inherit_check1 CHECK (indexrelname IS NULL OR indexrelname IS NOT NULL AND relname IS NOT NULL); 73 | ALTER TABLE index_watch.config ADD CONSTRAINT inherit_check2 CHECK (relname IS NULL OR relname IS NOT NULL AND schemaname IS NOT NULL); 74 | ALTER TABLE index_watch.config ADD CONSTRAINT inherit_check3 CHECK (schemaname IS NULL OR schemaname IS NOT NULL AND datname IS NOT NULL); 75 | 76 | 77 | CREATE VIEW index_watch.history AS 78 | SELECT date_trunc('second', entry_timestamp)::timestamp AS ts, 79 | datname AS db, schemaname AS schema, relname AS table, 80 | indexrelname AS index, pg_size_pretty(indexsize_before) AS size_before, 81 | pg_size_pretty(indexsize_after) AS size_after, 82 | (indexsize_before::float/indexsize_after)::numeric(12,2) AS ratio, 83 | pg_size_pretty(estimated_tuples) AS tuples, date_trunc('seconds', reindex_duration) AS duration 84 | FROM index_watch.reindex_history ORDER BY id DESC; 85 | 86 | 87 | --DEFAULT GLOBAL settings 88 | INSERT INTO index_watch.config (key, value, comment) VALUES 89 | ('index_size_threshold', '10MB', 'ignore indexes under 10MB size unless forced entries found in history'), 90 | ('index_rebuild_scale_factor', '2', 'rebuild indexes by default estimated bloat over 2x'), 91 | ('minimum_reliable_index_size', '128kB', 'small indexes not reliable to use as gauge'), 92 | ('reindex_history_retention_period','10 years', 'reindex history default retention pcommenteriod') 93 | ; 94 | 95 | --DEFAULT per any DB setting 96 | INSERT INTO index_watch.config (datname, schemaname, relname, indexrelname, key, value, comment) VALUES 97 | ('*', 'repack', NULL, NULL, 'skip', 'true', 'skip repack internal schema'), 98 | ('*', 'pgq', 'event_*', NULL, 'skip', 'true', 'skip pgq transient tables') 99 | ; 100 | 101 | 102 | --current version of table structure 103 | CREATE TABLE index_watch.tables_version 104 | ( 105 | version smallint NOT NULL 106 | ); 107 | CREATE UNIQUE INDEX tables_version_single_row ON index_watch.tables_version((version IS NOT NULL)); 108 | INSERT INTO index_watch.tables_version VALUES(8); 109 | 110 | 111 | -- current proccessed index can be invalid 112 | CREATE TABLE index_watch.current_processed_index 113 | ( 114 | id bigserial primary key, 115 | mtime timestamptz not null default now(), 116 | datname name not null, 117 | schemaname name not null, 118 | relname name not null, 119 | indexrelname name not null 120 | ); 121 | --------------------------------------------------------------------------------