标签云
asm恢复 bbed bootstrap$ dul In Memory kcbzib_kcrsds_1 kccpb_sanity_check_2 kfed MySQL恢复 ORA-00312 ORA-00607 ORA-00704 ORA-01110 ORA-01555 ORA-01578 ORA-08103 ORA-600 2131 ORA-600 2662 ORA-600 2663 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)
- 操作系统 (102)
- 数据库 (1,683)
- DB2 (22)
- MySQL (73)
- Oracle (1,545)
- Data Guard (52)
- EXADATA (8)
- GoldenGate (24)
- ORA-xxxxx (159)
- ORACLE 12C (72)
- ORACLE 18C (6)
- ORACLE 19C (15)
- ORACLE 21C (3)
- Oracle 23ai (7)
- Oracle ASM (68)
- Oracle Bug (8)
- Oracle RAC (53)
- Oracle 安全 (6)
- Oracle 开发 (28)
- Oracle 监听 (28)
- Oracle备份恢复 (565)
- Oracle安装升级 (92)
- Oracle性能优化 (62)
- 专题索引 (5)
- 勒索恢复 (79)
- PostgreSQL (18)
- PostgreSQL恢复 (6)
- SQL Server (27)
- SQL Server恢复 (8)
- TimesTen (7)
- 达梦数据库 (2)
- 生活娱乐 (2)
- 至理名言 (11)
- 虚拟化 (2)
- VMware (2)
- 软件开发 (37)
- Asp.Net (9)
- JavaScript (12)
- PHP (2)
- 小工具 (20)
-
最近发表
- ORA-15411: Failure groups in disk group DATA have different number of disks.
- 断电引起的ORA-08102: 未找到索引关键字, 对象号 39故障处理
- ORA-00227: corrupt block detected in control file
- 手工删除19c rac
- 解决oracle数据文件路径有回车故障
- .wstop扩展名勒索数据库恢复
- Oracle Recovery Tools工具一键解决ORA-00376 ORA-01110故障(文件offline)
- OGG-02771 Input trail file format RELEASE 19.1 is different from previous trail file form at RELEASE 11.2.
- OGG-02246 Source redo compatibility level 19.0.0 requires trail FORMAT 12.2 or higher
- GoldenGate 19安装和打patch
- dd破坏asm磁盘头恢复
- 删除asmlib磁盘导致磁盘组故障恢复
- Kylin Linux 安装19c
- ORA-600 krse_arc_complete.4
- Oracle 19c 202410补丁(RUs+OJVM)
- ntfs MFT损坏(ntfs文件系统故障)导致oracle异常恢复
- .mkp扩展名oracle数据文件加密恢复
- 清空redo,导致ORA-27048: skgfifi: file header information is invalid
- A_H_README_TO_RECOVER勒索恢复
- 通过alert日志分析客户自行对一个数据库恢复的来龙去脉和点评
标签归档:exp排除表
exp跳过某些表导出数据
有一个需求,某个用户有很多张表,但是只能使用exp导出,而且想跳过其中某几张表,其他对象包括依赖关系都需要。针对这样的情况,通过分析exp的视图脚本,在exu10tabs视图进行修改,跳过某些表即可
修改exu10tabs视图
本测试为11.2.0.4版本,不同版本数据库,可能视图名称和语句有一定出入,请别照搬,exu10tabs在$ORACLE_HOME/rdbms/admin/catexp.sql中
CREATE OR REPLACE VIEW exu10tabs ( objid, dobjid, name, owner, ownerid, tablespace, tsno, fileno, blockno, audit$, comment$, clusterflag, mtime, modified, tabno, pctfree$, pctused$, initrans, maxtrans, degree, instances, cache, tempflags, property, deflog, tsdeflog, roid, recpblk, secondaryobj, rowcnt, blkcnt, avgrlen, tflags, trigflag, objstatus, xdbool) AS /* Heap tables */ SELECT o$.obj#, o$.dataobj#, o$.name, u$.name, o$.owner#, ts$.name, t$.ts#, t$.file#, t$.block#, t$.audit$, c$.comment$, NVL(t$.bobj#, 0), o$.mtime, DECODE(BITAND(t$.flags, 1), 1, 1, 0), NVL(t$.tab#, 0), MOD(t$.pctfree$, 100), t$.pctused$, t$.initrans, t$.maxtrans, NVL(t$.degree, 1), NVL(t$.instances, 1), DECODE(BITAND(t$.flags, 8), 8, 1, 0), MOD(TRUNC(o$.flags / 2), 2), t$.property, DECODE(BITAND(t$.flags, 32), 32, 1, 0), ts$.dflogging, o$.oid$, t$.spare1, DECODE(BITAND(o$.flags, 16), 16, 1, 0), NVL(t$.rowcnt, -1), NVL(t$.blkcnt, -1), NVL(t$.avgrln, -1), t$.flags, t$.trigflag, o$.status, (SELECT COUNT(*) FROM sys.opqtype$ opq$ WHERE opq$.obj# = o$.obj# AND BITAND(opq$.flags, 32) = 32 ) FROM sys.tab$ t$, sys.obj$ o$, sys.ts$ ts$, sys.user$ u$, sys.com$ c$ WHERE t$.obj# = o$.obj# AND t$.ts# = ts$.ts# AND u$.user# = o$.owner# AND o$.obj# = c$.obj#(+) AND c$.col#(+) IS NULL AND BITAND(o$.flags,128) != 128 AND /* Skip recycle bin */ BITAND(t$.property, 64+512) = 0 AND /*skip IOT and ovflw segs*/ BITAND(t$.flags, 536870912) = 0 /* skip IOT mapping table */ and o$.name not in('T_XIFENFEI','T_ORASOS') --增加需要跳过表 UNION ALL /* Index-only tables */ SELECT o$.obj#, o$.dataobj#, o$.name, u$.name, o$.owner#, ts$.name, i$.ts#, t$.file#, t$.block#, t$.audit$, c$.comment$, NVL(t$.bobj#, 0), o$.mtime, DECODE(BITAND(t$.flags, 1), 1, 1, 0), NVL(t$.tab#, 0), 0, 0, 0, 0, NVL(t$.degree, 1), NVL(t$.instances, 1), DECODE(BITAND(t$.flags, 8), 8, 1, 0), MOD(TRUNC(o$.flags / 2), 2), t$.property, DECODE(BITAND(t$.flags, 32), 32, 1, 0), ts$.dflogging, o$.oid$, t$.spare1, DECODE(BITAND(o$.flags, 16), 16, 1, 0), NVL(t$.rowcnt, -1), NVL(t$.blkcnt, -1), NVL(t$.avgrln, -1), t$.flags, t$.trigflag, o$.status, (SELECT COUNT(*) FROM sys.opqtype$ opq$ WHERE opq$.obj# = o$.obj# AND BITAND(opq$.flags, 32) = 32 ) FROM sys.tab$ t$, sys.obj$ o$, sys.ts$ ts$, sys.user$ u$, sys.com$ c$, sys.ind$ i$ WHERE t$.obj# = o$.obj# AND u$.user# = o$.owner# AND o$.obj# = c$.obj#(+) AND c$.col#(+) IS NULL AND BITAND(o$.flags,128) != 128 AND /* Skip recycle bin */ BITAND(t$.property, 64+512) = 64 AND /* IOT, but not overflow*/ t$.pctused$ = i$.obj# AND/* For IOTs, pctused has index obj# */ i$.ts# = ts$.ts#
准备测试条件
创建用户xifenfei,在该用户下面创建四个表,其中有t_xifenfei和t_orasos需要跳过
[oracle@localhost ~]$ ss SQL*Plus: Release 11.2.0.4.0 Production on Sun Feb 21 21:38:18 2016 Copyright (c) 1982, 2013, Oracle. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production With the Partitioning, OLAP, Data Mining and Real Application Testing options SQL> create user xifenfei identified by oracle; User created. SQL> grant dba to xifenfei; Grant succeeded. SQL> conn xifenfei/oracle Connected. SQL> create table t_xifenfei as select * from dba_tables; Table created. SQL> create table t_xifenfei_exp as select * from dba_tables; Table created. SQL> create table t_orasos as select * from dual; Table created. SQL> create table xff_t_orasos as select * from dual; Table created. SQL> select * from tab; TNAME TABTYPE CLUSTERID ------------------------------ ------- ---------- T_ORASOS TABLE T_XIFENFEI TABLE T_XIFENFEI_EXP TABLE XFF_T_ORASOS TABLE
exp导出数据测试
[oracle@localhost ~]$ exp xifenfei/oracle owner=xifenfei file=/tmp/www.xifenfei.com.dmp Export: Release 11.2.0.4.0 - Production on Sun Feb 21 21:40:23 2016 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production With the Partitioning, OLAP, Data Mining and Real Application Testing options Export done in US7ASCII character set and AL16UTF16 NCHAR character set server uses ZHS16GBK character set (possible charset conversion) About to export specified users ... . exporting pre-schema procedural objects and actions . exporting foreign function library names for user XIFENFEI . exporting PUBLIC type synonyms . exporting private type synonyms . exporting object type definitions for user XIFENFEI About to export XIFENFEI's objects ... . exporting database links . exporting sequence numbers . exporting cluster definitions . about to export XIFENFEI's tables via Conventional Path ... . . exporting table T_XIFENFEI_EXP 3374 rows exported . . exporting table XFF_T_ORASOS 1 rows exported . exporting synonyms . exporting views . exporting stored procedures . exporting operators . exporting referential integrity constraints . exporting triggers . exporting indextypes . exporting bitmap, functional and extensible indexes . exporting posttables actions . exporting materialized views . exporting snapshot logs . exporting job queues . exporting refresh groups and children . exporting dimensions . exporting post-schema procedural objects and actions . exporting statistics Export terminated successfully without warnings.
通过测试,我们发现,在xifenfei用户中有四个表,按照我们的设想跳过了事先配置的表.通过修改exu10tabs脚本,完美实现exp跳部分表