标签云
asm恢复 bbed bootstrap$ dul kcbzib_kcrsds_1 kccpb_sanity_check_2 kcratr_nab_less_than_odr kgegpa MySQL恢复 ORA-00312 ORA-00704 ORA-00742 ORA-01110 ORA-01190 ORA-01200 ORA-01555 ORA-01578 ORA-01595 ORA-600 2662 ORA-600 3020 ORA-600 4000 ORA-600 4137 ORA-600 4193 ORA-600 4194 ORA-600 16703 ORA-600 kcbzib_kcrsds_1 ORA-600 KCLCHKBLK_4 ORA-15042 ORA-15196 ORACLE 12C oracle dul ORACLE PATCH Oracle Recovery Tools oracle加密恢复 oracle勒索 oracle勒索恢复 oracle异常恢复 ORACLE恢复 Oracle 恢复 ORACLE数据库恢复 oracle 比特币 OSD-04016 YOUR FILES ARE ENCRYPTED 勒索恢复 比特币加密文章分类
- Others (2)
- 中间件 (2)
- WebLogic (2)
- 操作系统 (106)
- 数据库 (1,801)
- DB2 (22)
- MySQL (79)
- Oracle (1,637)
- Data Guard (53)
- EXADATA (8)
- GoldenGate (24)
- ORA-xxxxx (166)
- ORACLE 12C (72)
- ORACLE 18C (6)
- ORACLE 19C (15)
- ORACLE 21C (3)
- Oracle 23ai (8)
- Oracle ASM (69)
- Oracle Bug (8)
- Oracle RAC (54)
- Oracle 安全 (6)
- Oracle 开发 (28)
- Oracle 监听 (29)
- Oracle备份恢复 (611)
- Oracle安装升级 (101)
- Oracle性能优化 (62)
- 专题索引 (5)
- 勒索恢复 (86)
- PostgreSQL (33)
- pdu工具 (7)
- PostgreSQL恢复 (11)
- SQL Server (32)
- SQL Server恢复 (13)
- TimesTen (7)
- 达梦数据库 (3)
- 达梦恢复 (1)
- 生活娱乐 (2)
- 至理名言 (11)
- 虚拟化 (2)
- VMware (2)
- 软件开发 (43)
- Asp.Net (9)
- JavaScript (12)
- PHP (2)
- 小工具 (26)
-
最近发表
- obet(Oracle Block Editor Tool)第二版发布
- Oracle数据块编辑工具( Oracle Block Editor Tool)-obet
- Oracle坏块修复工具:Patch_blk
- ORA-01172 ORA-01151故障处理
- C_OBJ#_INTCOL#坏块导致数据库无法open故障处理
- ORA-600 kkkicreatecgmap:!efn3
- Oracle 19c 202510补丁(RUs+OJVM)-19.29
- 记录一次raid恢复之后数据库故障处理(ora-01200,ORA-26101,ORA-600)
- nbu备份文件img格式直接rman恢复
- ORA-600 kokasgi1故障处理(sys被重命名)
- Patch_SCN for Linux 功能完善
- ORA-600 2662错误处理-202510
- system表空间丢失部分文件恢复
- arm环境vg损坏mysql数据库恢复
- redhat系列7/8进入单用户模式
- Failed to open \EFI\redhat\grubx64.efi – Not Found 故障处理
- 11.2.0.4升级到19c详细操作过程
- Postgres数据库truncate表无有效备份恢复
- 一次幸运的ORA-07445 kdxlin故障恢复
- ORA-704 ORA-604 ORA-1426故障分析处理
标签归档:pdu
PostgreSQL表文件损坏恢复—pdu恢复损坏的表文件
在某些情况下,由于PostgreSQL表文件损坏导致无法正常访问,可以通过pdu把好的block中的数据恢复出来
准备一张测试表,里面有97条记录
his5_dms=# \d hiscrm.t_sys_oper_log;
Table "hiscrm.t_sys_oper_log"
Column | Type | Collation | Nullable |Default
--------------------+------------------------+-----------+----------+------------
id | bigint | | not null |
module | character varying(50) | | |
title | character varying(50) | | |
alias | character varying(50) | | |
business_type | integer | | | 0
method | character varying(200) | | |
request_method | character varying(10) | | |
operator_type | integer | | | 0
oper_name | character varying(50) | | |
dept_name | character varying(50) | | |
oper_url | character varying(255) | | |
oper_ip | character varying(50) | | |
oper_location | character varying(255) | | |
oper_param | text | | |
json_result | text | | |
status | integer | | | 0
error_msg | text | | |
oper_time | date | | |
create_id | bigint | | |
create_time | bigint | | |
clinic_id | bigint | | |
group_id | bigint | | |
patient_id | bigint | | |
is_patient_related | integer | | |
business_content | json | | |
his5_dms=# select count(1) from hiscrm.t_sys_oper_log;
count
-------
97
(1 row)
查询表对应的具体文件
his5_dms=# SELECT oid,relfilenode FROM pg_class WHERE relname='t_sys_oper_log';
oid | relfilenode
-------+-------------
16850 | 16850
(1 row)
his5_dms=# SELECT pg_relation_filepath('hiscrm.t_sys_oper_log');
pg_relation_filepath
----------------------
base/16386/16850
(1 row)
his5_dms=# SHOW data_directory;
data_directory
------------------------
/var/lib/pgsql/12/data
(1 row)
使用dd对文件进行破坏
[postgres@xifenfeidg ~]$ ls -l /var/lib/pgsql/12/data/base/16386/16850 -rw-------. 1 postgres postgres 90112 Sep 5 20:26 /var/lib/pgsql/12/data/base/16386/16850 [postgres@xifenfeidg ~]$ dd if=/dev/zero of=/var/lib/pgsql/12/data/base/16386/16850 bs=512 count=1 conv=notrunc 1+0 records in 1+0 records out 512 bytes copied, 0.000158756 s, 3.2 MB/s
重启pg库
[postgres@xifenfeidg bin]$ ./pg_ctl -m fast -D /var/lib/pgsql/12/data/ stop waiting for server to shut down.... done server stopped [postgres@xifenfeidg bin]$ ./pg_ctl -D /var/lib/pgsql/12/data/ start waiting for server to start....2025-03-02 19:02:11.395 HKT [64515] LOG: starting PostgreSQL 12.20 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 8.5.0 20210514 (Red Hat 8.5.0-22), 64-bit 2025-03-02 19:02:11.396 HKT [64515] LOG: listening on IPv6 address "::1", port 5432 2025-03-02 19:02:11.396 HKT [64515] LOG: listening on IPv4 address "127.0.0.1", port 5432 2025-03-02 19:02:11.396 HKT [64515] LOG: listening on Unix socket "/var/run/postgresql/.s.PGSQL.5432" 2025-03-02 19:02:11.397 HKT [64515] LOG: listening on Unix socket "/tmp/.s.PGSQL.5432" 2025-03-02 19:02:11.403 HKT [64515] LOG: redirecting log output to logging collector process 2025-03-02 19:02:11.403 HKT [64515] HINT: Future log output will appear in directory "log". done server started
查询数据报错
[postgres@xifenfeidg bin]$ psql psql (16.8, server 12.20) Type "help" for help. postgres=# \c his5_dms; psql (16.8, server 12.20) You are now connected to database "his5_dms" as user "postgres". his5_dms=# select count(1) from hiscrm.t_sys_oper_log; ERROR: invalid page in block 0 of relation base/16386/16850
通过pdu进行恢复
跳过了坏块,把好的block中数据均恢复出来
his5_dms.hiscrm=# unload tab t_sys_oper_log;
正在解析表 <t_sys_oper_log>. 已解析数据页: 0, 已解析数据: 0 条
|-块号0 空页面或页面已损坏,已跳过
正在解析表 <t_sys_oper_log>. 已解析数据页: 11, 已解析数据: 86 条
表名<t_sys_oper_log>-</var/lib/pgsql/12/data/base/16386/16850>
解析完成, 11 个数据页 ,共计 86 条数据. 成功 86 条; 失败【0】条
COPY文件路径为:<his5_dms/hiscrm/t_sys_oper_log.csv>
导入pg库中
his5_dms=# truncate table hiscrm.t_sys_oper_log; TRUNCATE TABLE his5_dms=# \i his5_dms/COPY/hiscrm_copy.sql SET COPY 86 his5_dms=#
PostgreSQL恢复工具—pdu恢复单个表文件
在某些情况下,比如我们需要对单个的PostgreSQL库的表文件进行恢复(比如文件系统损坏,drop库/表,truncate表等原因,然后找到了部分oid文件),可以使用pdu对其进行完美恢复(相比pg_filedump也方便很多),具体操作步骤:
1. 由于只有单个表文件,无法获取字典信息,因此需要应用厂商/客户提供具体表创建语句
his5_dms=# CREATE TABLE t_xff ( his5_dms(# id bigint, his5_dms(# hospital_id bigint, his5_dms(# parent_id bigint, his5_dms(# disease_code varchar(60), his5_dms(# disease_name varchar(60), his5_dms(# type smallint, his5_dms(# py varchar(60), his5_dms(# wb varchar(60), his5_dms(# sc varchar(20), his5_dms(# order_no int, his5_dms(# state smallint, his5_dms(# create_datetime timestamp(6), his5_dms(# create_id bigint, his5_dms(# edit_datetime timestamp(6), his5_dms(# edit_id bigint, his5_dms(# search_path varchar(300), his5_dms(# diagnosis_sort int, his5_dms(# category_name varchar(40), his5_dms(# input_option varchar(40), his5_dms(# category_class smallint, his5_dms(# memo1 varchar(300), his5_dms(# memo2 varchar(300), his5_dms(# other_code varchar(60), his5_dms(# other_name varchar(60), his5_dms(# special_disease_flag smallint his5_dms(# ); CREATE TABLE
2. 把oid文件pdu放到restore库中
[root@xifenfeidg public]# pwd /tmp/pdu/restore/public [root@xifenfeidg public]# ls -l total 7144 -rw-r--r--. 1 root root 7315456 Mar 2 21:04 123456 [root@xifenfeidg public]#
3. 使用add语句在pdu加载数据类型
restore.public=# add 123456 t_xff bigint,bigint,bigint,varchar,varchar,smallint,varchar,varchar,varchar,
int,smallint,timestamp,bigint,timestamp,bigint,varchar,int,varchar,varchar,
smallint,varchar,varchar,varchar,varchar,smallint;
添加完成,请用\dt;查看可unload的表
restore.public=# \dt;
|--------------------------------------------------|
| 表名 | 表大小 |
|--------------------------------------------------|
| t_xff | 6.98 MB |
|--------------------------------------------------|
仅显示表大小排名前 1 的表名
4.使用pdu恢复表数据
restore.public=# unload t_xff; 正在解析表 <t_xff>. 已解析数据页: 893, 已解析数据: 46998 条 <t_xff>-<restore/public/123456> 解析完成, 894 个数据页 ,共计 46998 条数据. 成功 46998 条; 失败【0】条 COPY文件路径为:<restore/public/t_xff.csv> restore.public=# unload COPY; COPY命令导出完成, 文件路径: restore/COPY/public_copy.sql
5.导入数据到pg库中
his5_dms=# \i restore/COPY/public_copy.sql SET COPY 46998 his5_dms=# select count(1) from t_xff; count ------- 46998 (1 row) his5_dms=# \x Expanded display is on. his5_dms=# select * from t_xff limit 1; -[ RECORD 1 ]--------+--------------------------- id | 323839 hospital_id | 0 parent_id | 301 disease_code | 57.8900x003 disease_name | 腹腔镜下膀胱颈悬吊术 type | 2 py | fqjxpgjxds wb | eeqgeeceks sc | order_no | 0 state | 1 create_datetime | 2022-09-29 15:22:58.588492 create_id | edit_datetime | edit_id | search_path | 301, diagnosis_sort | category_name | input_option | category_class | 3 memo1 | memo2 | other_code | other_name | special_disease_flag | 0
PostgreSQL恢复工具—pdu工具介绍
张晨同学开发了一个PostgreSQL数据恢复工具PDU(PDU: Postgresql Data Rescue Tool),我这边配合做一些测试
使用帮助命令
PDU.public=# ; PDU数据拯救工具 | 命令帮助 ━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━ **基础操作** b; │ 初始化数据库元信息 exit; │ 退出工具 **数据库切换** use <db>; │ 指定目标数据库 (例: use logs;) set <schema>; │ 指定操作模式 (例: set recovery;) **元数据展示** \l; │ 列出所有数据库 \dn; │ 显示当前数据库模式 \dt; │ 列出当前模式下的表 \d+ <table>; │ 查看表结构详情 (例: \d+ users;) \d <table>; │ 查看表列类型 (例: \d users;) **数据导出** unload <table>; │ 导出表数据 → ./<表名>.csv (例: unload orders;) unload SCH; │ 导出当前模式所有数据 unload DDL; │ 生成模式结构定义文件 unload COPY; │ 生成PSQL COPY语句脚本 **误删数据恢复** scan t1; │ 扫描被误删的表 restore del <Tx Number>; │ 通过事务号恢复被误删的数据 -------------------------------------------------------------------------------------- scan drop; │ 扫描wal日志中的drop事务 restore drop <Tx Number>; │ 通过事务号恢复被drop的表 add <oid> <tablename> <attibutes>; │ 将表信息手动添加到restore库中 例如: <add 12345 t1 varchar,varchar,timestamp,varchar,numeric,varchar,varchar,varchar,numeric;> ━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━ 语法规则 ◈ 指令后缀必须带 `;`
加载PostgreSQL元数据
PDU.public=# b;
开始初始化...
-pg_database:</var/lib/pgsql/12/data/global/1262>
【postgres】
-pg_schema:</var/lib/pgsql/12/data/base/14399/2615>
-pg_class:</var/lib/pgsql/12/data/base/14399/1259>,共55行
-pg_attribute:</var/lib/pgsql/12/data/base/14399/1249>,共2913行
模式:
-->public,2张表
【his5_dms】
-pg_schema:</var/lib/pgsql/12/data/base/16386/2615>
-pg_class:</var/lib/pgsql/12/data/base/16386/1259>,共793行
-pg_attribute:</var/lib/pgsql/12/data/base/16386/1249>,共31329行
模式:
-->public,660张表
-->hiscrm,55张表
-->pgagent,8张表
-->report,7张表
-->statistics,10张表
查看当前有哪些库
PDU.public=# \l;
|------------------|
| 数据库名 |
|------------------|
| postgres |
| template1 |
| template0 |
| his5_dms |
| restore |
|------------------|
5 rows selected
进入某个库
PDU.public=# use his5_dms; |----------------------------------------| | 模式 | 表数量 | |----------------------------------------| | public | 660 | | hiscrm | 55 | | pgagent | 8 | | report | 7 | | statistics | 10 | |----------------------------------------|
进入某个模式
his5_dms.public=# set hiscrm;
|--------------------------------------------------|
| 表名 | 表大小 |
|--------------------------------------------------|
| t_patient_other | 600.00 KB |
| t_sys_oper_log | 88.00 KB |
| t_auth | 88.00 KB |
| t_setting_user | 56.00 KB |
| t_field_define | 32.00 KB |
| t_oper_log | 16.00 KB |
| t_role | 16.00 KB |
| t_sys_login_log | 8.00 KB |
| t_appointment_item | 8.00 KB |
| t_clinic | 8.00 KB |
| t_dept | 8.00 KB |
| t_employee | 8.00 KB |
| t_menu | 8.00 KB |
| t_patient_label | 8.00 KB |
| t_patient_label_detail_tpl | 8.00 KB |
| t_patient_source_ref | 8.00 KB |
| t_return_visit_tpl | 8.00 KB |
| t_setting_clinic | 8.00 KB |
| t_setting_notify | 8.00 KB |
| t_sms_template_category | 8.00 KB |
|--------------------------------------------------|
仅显示表大小排名前 50 的表名
显示部分表
his5_dms.hiscrm=# \dt;
|--------------------------------------------------|
| 表名 | 表大小 |
|--------------------------------------------------|
| t_patient_other | 600.00 KB |
| t_sys_oper_log | 88.00 KB |
| t_auth | 88.00 KB |
| t_setting_user | 56.00 KB |
| t_field_define | 32.00 KB |
| t_oper_log | 16.00 KB |
| t_role | 16.00 KB |
| t_sys_login_log | 8.00 KB |
| t_appointment_item | 8.00 KB |
| t_clinic | 8.00 KB |
| t_dept | 8.00 KB |
| t_employee | 8.00 KB |
| t_menu | 8.00 KB |
| t_patient_label | 8.00 KB |
| t_patient_label_detail_tpl | 8.00 KB |
| t_patient_source_ref | 8.00 KB |
| t_return_visit_tpl | 8.00 KB |
| t_setting_clinic | 8.00 KB |
| t_setting_notify | 8.00 KB |
| t_sms_template_category | 8.00 KB |
|--------------------------------------------------|
仅显示表大小排名前 50 的表名
显示某个表的信息
his5_dms.hiscrm=# \d+ t_auth;
----------------------------------------------------------------
| 建表语句 |
----------------------------------------------------------------
CREATE TABLE t_auth (
id bigint,
clinic_id bigint,
group_id bigint,
parient_id varchar(64),
menu_id varchar(64),
auth_key varchar(60),
auth_name varchar(64),
uris varchar,
rely varchar(255),
state bigint,
sort bigint,
tag bigint,
explain varchar(255),
desc varchar(255)
);
----------------------------------------------------------------
| |
----------------------------------------------------------------
his5_dms.hiscrm=# \d t_auth;
----------------------------------------------------------------
| 列类型 |
----------------------------------------------------------------
bigint,bigint,bigint,varchar,varchar,varchar,varchar,varchar,varchar,bigint,bigint,bigint,varchar,varchar
恢复表数据
his5_dms.hiscrm=# unload t_auth; 正在解析表 <t_auth>. 已解析数据页: 11, 已解析数据: 492 条 <t_auth>-</var/lib/pgsql/12/data/base/16386/16895> 解析完成, 12 个数据页 ,共计 492 条数据. 成功 492 条; 失败【0】条 COPY文件路径为:<his5_dms/hiscrm/t_auth.csv>
确认恢复表的数据情况
[root@xifenfeidg hiscrm]# wc -l t_auth.csv 492 t_auth.csv

PostgreSQL中查询表实际数据情况
his5_dms=# select count(1) from hiscrm.t_auth;
count
-------
492
(1 row)
is5_dms=# \d hiscrm.t_auth;
Table "hiscrm.t_auth"
Column | Type | Collation | Nullable | Default
------------+------------------------+-----------+----------+-------------------------
id | bigint | | not null |
clinic_id | bigint | | |
group_id | bigint | | |
parient_id | character varying(64) | | not null |
menu_id | character varying(64) | | not null |
auth_key | character varying(60) | | not null |
auth_name | character varying(64) | | not null |
uris | text | | not null |
rely | character varying(255) | | | NULL::character varying
state | bigint | | not null |
sort | bigint | | not null |
tag | bigint | | | '0'::bigint
explain | character varying(255) | | | NULL::character varying
desc | character varying(255) | | | NULL::character varying
truncate表
his5_dms=# truncate table hiscrm.t_auth;
TRUNCATE TABLE
his5_dms=# select count(1) from hiscrm.t_auth;
count
-------
0
(1 row)
导入数据,并验证恢复效果
his5_dms=# \i /tmp/pdu/his5_dms/COPY/hiscrm_copy.sql SET COPY 492 his5_dms=# select count(1) from hiscrm.t_auth; count ------- 492 (1 row)
通过验证pdu可以在数据库离线的情况下,恢复PostgreSQL数据库中表的数据,更加方便和灵活的实现替代pg_filedump功能,而且pdu还在不断完善和新功能更新中

加我QQ(107644445)
