合 Oracle之dual系列
前言部分
导读和注意事项
各位技术爱好者,看完本文后,你可以掌握如下的技能,也可以学到一些其它你所不知道的知识,~O(∩_∩)O~:
① DUAL遭到破坏后的重建(重点)
② 关于参数replication_dependency_tracking简介
③ DUAL简介
本文简介
DUAL系列很早之前是看杨建荣的blog了解到的,最近又看他的书又看见了这块内容,于是决定自己整理一下。在此,小麦苗还是想说的是看书和自己做实验是完全不同的2回事,不多说了。
dual官方文档说明
DUAL is a table automatically created by Oracle Database along with the data dictionary. DUAL is in the schema of the user SYS but is accessible by the name DUAL to all users. It has one column, DUMMY, defined to be VARCHAR2(1), and contains one row with a value X. Selecting from the DUAL table is useful for computing a constant expression with the SELECT statement. Because DUAL has only one row, the constant is returned only once. Alternatively, you can select a constant, pseudocolumn, or expression from any table, but the value will be returned as many times as there are rows in the table. Refer to "About SQL Functions" for many examples of selecting a constant value from DUAL.
Note:
Beginning with Oracle Database 10g Release 1, logical I/O is not performed on the DUAL table when computing an expression that does not include the DUMMY column. This optimization is listed as FAST DUAL in the execution plan. If you SELECT the DUMMY column from DUAL, then this optimization does not take place and logical I/O occurs.
DUAL总结
有关Oracle的DUAL表,我们需要掌握以下几点:
- DUAL是系统提供的一个虚表,也常称为DUMMY表,临时显示结果的表,里边的内容没有特定的意义,就是为了存在而存在
- DUAL是属于SYS SCHEMA的一个表,然后以PUBLIC SYNONYM的方式供其他数据库USER使用,这一点可以由如下SQL验证:
SYS@lhrdb> col owner format a15
SYS@lhrdb> col object_name format a15
SYS@lhrdb> SELECT D.OWNER,D.OBJECT_NAME,D.OBJECT_ID,D.OBJECT_TYPE FROM DBA_OBJECTS D WHERE D.OBJECT_NAME='DUAL';
OWNER OBJECT_NAME OBJECT_ID OBJECT_TYPE
--------------- --------------- ---------- -------------------
SYS DUAL 91680 TABLE
PUBLIC DUAL 117 SYNONYM
- ORACLE对DUAL表的操作做了一些内部处理,尽量保证DUAL表中只返回一条记录,当然这些内部操作是不可见的。我们尝试往DUAL表中插入多条记录,但始终显示的是一条记录。
SYS@lhrdb> INSERT INTO DUAL VALUES('X');
1 row created.
SYS@lhrdb> COMMIT;
Commit complete.
SYS@lhrdb> INSERT INTO DUAL VALUES('X');
1 row created.
SYS@lhrdb> COMMIT;
Commit complete.
SYS@lhrdb> select * from dual;
D
-
X
- DUAL表出现问题,所有相关的基础操作都会受到影响;若是DUAL表被删除的话,数据库将不能启动,报ORA-01775的错误。
- DUAL表在数据库启动的不同阶段,里边的字段还是会有一些不同。在数据库OPEN状态下是一行一列的表,在mount和nomount状态下是一行四列的表,验证如下:
SYS@lhrdb> startup force nomount
ORACLE instance started.
Total System Global Area 1720328192 bytes
Fixed Size 2247072 bytes
Variable Size 486540896 bytes
Database Buffers 1224736768 bytes
Redo Buffers 6803456 bytes
SYS@lhrdb> select * from dual;
ADDR INDX INST_ID DU
---------------- ---------- ---------- --
0000000110299728 0 1 X
SYS@lhrdb> alter database mount;
Database altered.
SYS@lhrdb> select * from dual;
ADDR INDX INST_ID D
---------------- ---------- ---------- -
0000000110299728 0 1 X
SYS@lhrdb> alter database open;
Database altered.
SYS@lhrdb> select * from dual;
D
-
X
- DUAL的常用方式
- 查看当前连接用户 SELECT USER FROM DUAL;
- 查看当前日期、时间 SELECT TO_CHAR(SYSDATE,'YYYY-MM-DD HH24:MI:SS') FROM DUAL;
- 当作计算器用 SELECT 8*9 FROM DUAL;
- 查看序列值 SELECT MYSEQ.NEXTVAL FROM DUAL;
DUAL表破坏后的恢复
项目 | db |
---|---|
db 类型 | single db |
db version | 11.2.0.4.0 |
db 存储 | ASM |
OS版本及kernel版本 | AIX 64位 7.1.0.0 |
我们首先删除SYS用户下的DUAL表:
SYS@lhrdb> SHOW USER
USER is "SYS"
SYS@lhrdb> SELECT COUNT(*) FROM DBA_OBJECTS D WHERE D.status='INVALID';
COUNT(*)
----------
0
SYS@lhrdb> DROP TABLE DUAL;
Table dropped.
SYS@lhrdb> SELECT * FROM DUAL;
SELECT * FROM DUAL
*
ERROR at line 1:
ORA-01775: looping chain of synonyms
SYS@lhrdb> SELECT COUNT(*) FROM DBA_OBJECTS D WHERE D.status='INVALID';
COUNT(*)
----------
1042
SYS@lhrdb> SET PAGESIZE 9999
SYS@lhrdb> SELECT D.OWNER, COUNT(*) FROM DBA_OBJECTS D WHERE D.status='INVALID' GROUP BY D.OWNER;
OWNER COUNT(*)
------------------------------ ----------
PUBLIC 222
XDB 7
OLAPSYS 43
APEX_030200 157
SYS 403
MDSYS 44
SYSMAN 66
EXFSYS 23
ORACLE_OCM 1
WMSYS 42
ORDSYS 11
IX 6
CTXSYS 15
DBSNMP 1
OE 1
15 rows selected.
SYS@lhrdb>
可以看到删除DUAL表的时候并没有报错,但是查询的时候报错了,并且系统中大约有1000多个对象变为了无效的状态,业务系统中的PL/SQL代码中含有大量的DUAL查询,若是该表被删除,对系统的影响是非常大的。
查看告警日志,也有一些错误报出:
Errors in file /oracle/app/oracle/diag/rdbms/lhrdb/lhrdb/trace/lhrdb_m001_41877662.trc:
ORA-00604: error occurred at recursive SQL level 1
ORA-04063: package body "SYS.PRVT_HDM" has errors
ORA-06508: PL/SQL: could not find program unit being called: "SYS.PRVT_HDM"
ORA-06512: at line 1
Wed Aug 10 10:02:40 2016
Errors in file /oracle/app/oracle/diag/rdbms/lhrdb/lhrdb/trace/lhrdb_j000_11075780.trc:
ORA-12012: error on auto execute of job 4002
ORA-01775: looping chain of synonyms
DUAL的恢复分为2种情况,一种是数据库在没有重启的情况下,第二种是数据库在重启的情况下,但是总的恢复原则都是在数据库OPEN状态下重建DUAL表,下边我们分别测试。
不重启数据库
不重启数据库的情况下我们可以采用重建DUAL表,插入DUMMY的数据。
SYS@lhrdb> CREATE TABLE SYS.DUAL(DUMMY VARCHAR2(1)) STORAGE(INITIAL 1) TABLESPACE SYSTEM;
Table created.
SYS@lhrdb> INSERT INTO DUAL VALUES('X');
1 row created.
SYS@lhrdb> COMMIT;
Commit complete.
SYS@lhrdb> CREATE OR REPLACE PUBLIC SYNONYM DUAL FOR DUAL;
Synonym created.
SYS@lhrdb> GRANT SELECT ON DUAL TO PUBLIC WITH GRANT OPTION;
Grant succeeded.
SYS@lhrdb> SELECT * FROM DUAL;
D
-
X
SYS@lhrdb> SELECT SYSDATE FROM DUAL;
SYSDATE
-------------------
2016-08-10 10:22:37
SYS@lhrdb> SELECT COUNT(*) FROM DBA_OBJECTS D WHERE D.status='INVALID';
COUNT(*)
----------
1041
SYS@lhrdb> SELECT D.OWNER, COUNT(*) FROM DBA_OBJECTS D WHERE D.status='INVALID' GROUP BY D.OWNER;
OWNER COUNT(*)
------------------------------ ----------
PUBLIC 222
XDB 7
OLAPSYS 43
APEX_030200 157
SYS 402
MDSYS 44
SYSMAN 66
EXFSYS 23
ORACLE_OCM 1
WMSYS 42
ORDSYS 11
IX 6
CTXSYS 15
DBSNMP 1
OE 1
15 rows selected.
SYS@lhrdb> col owner format a15
SYS@lhrdb> col object_name format a15
SYS@lhrdb> SELECT D.OWNER,D.OBJECT_NAME,D.OBJECT_ID,D.OBJECT_TYPE FROM DBA_OBJECTS D WHERE D.OBJECT_NAME='DUAL';
OWNER OBJECT_NAME OBJECT_ID OBJECT_TYPE
--------------- --------------- ---------- -------------------
SYS DUAL 91680 TABLE
PUBLIC DUAL 117 SYNONYM
可以看到DUAL表已经重建成功了,但是还有很多的无效对象,下边我们利用脚本@?/rdbms/admin/utlrp.sql来重新编译这些对象。
SYS@lhrdb> @?/rdbms/admin/utlrp.sql
TIMESTAMP
--------------------------------------------------------------------------------
COMP_TIMESTAMP UTLRP_BGN 2016-08-10 10:25:13
DOC> The following PL/SQL block invokes UTL_RECOMP to recompile invalid
DOC> objects in the database. Recompilation time is proportional to the
DOC> number of invalid objects in the database, so this command may take
DOC> a long time to execute on a database with a large number of invalid
DOC> objects.
DOC>
DOC> Use the following queries to track recompilation progress:
DOC>
DOC> 1. Query returning the number of invalid objects remaining. This
DOC> number should decrease with time.
DOC> SELECT COUNT(*) FROM obj$ WHERE status IN (4, 5, 6);
DOC>
DOC> 2. Query returning the number of objects compiled so far. This number
DOC> should increase with time.
DOC> SELECT COUNT(*) FROM UTL_RECOMP_COMPILED;
DOC>
DOC> This script automatically chooses serial or parallel recompilation
DOC> based on the number of CPUs available (parameter cpu_count) multiplied
DOC> by the number of threads per CPU (parameter parallel_threads_per_cpu).
DOC> On RAC, this number is added across all RAC nodes.
DOC>
DOC> UTL_RECOMP uses DBMS_SCHEDULER to create jobs for parallel
DOC> recompilation. Jobs are created without instance affinity so that they
DOC> can migrate across RAC nodes. Use the following queries to verify