点击蓝字 阅读更多干货
Postgresql10版本开始提供了该插件验证索引或者是表的逻辑一致性。比如系统升级后,collate和原来不一致,数据库里索引的顺序和该collate不匹配。物理磁盘损坏,文件系统损坏,内存故障等,导致数据库中的索引也损坏。
可以通过该插件进行验证检测,注意该插件只验证,不会修补。如果通过该插件找出相应的索引,可以使用reindex命令重建索引,如果数据库很小,也可以考虑使用reindexdb重建整个库的索引。
另外从PG14版本开始新增了verify_heapam,可以验证表的数据页。
相关函数:
bt_index_check --加accessshared,和select类似bt_index_parent_check --加ShareLock锁,和DML均会冲突,所以使用该函数要注意
使用例子:
bt_index_check
test=# SELECT bt_index_check(index => c.oid, heapallindexed => i.indisunique),c.relname,c.relpagesFROM pg_index iJOIN pg_opclass op ON i.indclass[0] = op.oidJOIN pg_am am ON op.opcmethod = am.oidJOIN pg_class c ON i.indexrelid = c.oidJOIN pg_namespace n ON c.relnamespace = n.oidWHERE am.amname = 'btree' AND n.nspname = 'pg_catalog'-- Don't check temp tables, which may be from another session:AND c.relpersistence != 't'-- Function may throw an error when this is omitted:AND c.relkind = 'i' AND i.indisready AND i.indisvalidORDER BY c.relpages DESC LIMIT 10;bt_index_check | relname | relpages----------------+---------------------------------+----------| pg_depend_reference_index | 43| pg_depend_depender_index | 40| pg_proc_proname_args_nsp_index | 31| pg_description_o_c_o_index | 21| pg_attribute_relid_attnam_index | 14| pg_proc_oid_index | 10| pg_attribute_relid_attnum_index | 9| pg_amproc_fam_proc_index | 5| pg_amop_opr_fam_index | 5| pg_amop_fam_strat_index | 5(10 rows)
bt_index_parent_check
--验证tbl表的b-tree索引create extension if not exists amcheck;set statement_timeout to 0;do $$declarer record;sql text;ts_pre timestamptz;e_message text;e_detail text;e_context text;e_hint text;errcount int := 0;beginraise info 'begin!...';for r inselectrow_number() over(order by tc.reltuples) as i,count(*) over() as cnt,c.oid,i.indisunique,c.relname,c.relpages::int8,tc.reltuples::int8 as tuplesfrom pg_index ijoin pg_opclass op on i.indclass[0] = op.oidjoin pg_am am on op.opcmethod = am.oidjoin pg_class c on i.indexrelid = c.oidjoin pg_class tc on i.indrelid = tc.oidjoin pg_namespace n on c.relnamespace = n.oidwheream.amname = 'btree'--and n.nspname = 'public'and c.relpersistence <> 't' -- don't check temp tablesand c.relkind = 'i'and i.indisreadyand i.indisvalidand tc.relname = 'tbl' -- comment this out to check the whole DB--and c.relname in ('index_projects_on_name_and_id', 'index_projects_on_lower_name', 'index_projects_api_name_id_desc')order by tc.reltuplesloopts_pre := clock_timestamp();raise info '[%] Processing %/%: index: % (index relpages: %; heap tuples: ~%)...',ts_pre::timestamptz(3), r.i, r.cnt, r.relname, r.relpages, r.tuples;beginperform bt_index_parent_check(index => r.oid, heapallindexed => true);raise info '[%] SUCCESS %/% – index: %. Time taken: %',clock_timestamp()::timestamptz(3), r.i, r.cnt, r.relname, (clock_timestamp() - ts_pre);exception when others thenget stacked diagnosticse_message = message_text,e_detail = pg_exception_detail,e_context = pg_exception_context,e_hint = pg_exception_hint;errcount := errcount + 1;raise warning $err$[%] FAILED %/% – index: %.ERROR: %CONTEXT: %DETAIL: %HINT: %$err$,clock_timestamp()::timestamptz(3), r.i, r.cnt, r.relname, e_message, e_detail, e_context, e_hint;end;end loop;if errcount = 0 thenraise info 'Btree index scan with amcheck successfully finished. 0 errors.';elseraise exception 'Index corruption detected by amcheck, % errors, see details in the log.', errcount;end if;end $$;INFO: begin!...INFO: [2021-12-20 14:52:14.679+08] Processing 1/1: index: tbl_pkey (index relpages: 552; heap tuples: ~200300)...INFO: [2021-12-20 14:52:14.681+08] SUCCESS 1/1 – index: tbl_pkey. Time taken: 00:00:00.002516INFO: Btree index scan with amcheck successfully finished. 0 errors.DO
参考:
https://www.postgresql.org/docs/current/amcheck.html
https://elephanttamer.net/?p=61


分享、在看与点赞,至少我要拥有一个吧
文章转载自 晟数学苑,如果涉嫌侵权,请发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




