标签云
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,682)
- DB2 (22)
- MySQL (73)
- Oracle (1,544)
- 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 (67)
- 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-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日志分析客户自行对一个数据库恢复的来龙去脉和点评
- ORA-12514: TNS: 监听进程不能解析在连接描述符中给出的SERVICE_NAME
标签归档:_optimizer_null_aware_antijoin
_optimizer_null_aware_antijoin和not in效率
准备两个测试表
SQL> conn chf/oracle Connected. SQL> select * from v$version; BANNER ---------------------------------------------------------------------------- Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production PL/SQL Release 11.2.0.4.0 - Production CORE 11.2.0.4.0 Production TNS for Linux: Version 11.2.0.4.0 - Production NLSRTL Version 11.2.0.4.0 - Production SQL> create table t_xifenfei 2 as select * from dba_objects; Table created. SQL> select count(*) from t_xifenfei; COUNT(*) ---------- 86259 SQL> create table t_xifenfei1 2 as select * from dba_objects; Table created. SQL> select count(*) from t_xifenfei1; COUNT(*) ---------- 86260 --删除部分记录,用来做not in的内部表 SQL> delete from t_xifenfei where object_id>86200; 918 rows deleted. SQL> commit; Commit complete.
查询_optimizer_null_aware_antijoin隐含参数默认值
SQL> conn / as sysdba Connected. SQL> col name for a52 SQL> col value for a24 SQL> col description for a50 set linesize 150 select a.ksppinm name,b.ksppstvl value,a.ksppdesc description from x$ksppi a,x$ksppcv b where a.inst_id = USERENV ('Instance') and b.inst_id = USERENV ('Instance') and a.indx = b.indx and upper(a.ksppinm) LIKE upper('%¶m%') order by name SQL> SQL> 2 3 4 5 6 7 8 / Enter value for param: _optimizer_null_aware_antijoin old 6: and upper(a.ksppinm) LIKE upper('%¶m%') new 6: and upper(a.ksppinm) LIKE upper('%_optimizer_null_aware_antijoin%') NAME VALUE DESCRIPTION ---------------------------------------------------- ------------------------ ----------------------------- _optimizer_null_aware_antijoin TRUE null-aware antijoin parameter
_optimizer_null_aware_antijoin从11.1.0.6开始引进,默认为true
_optimizer_null_aware_antijoin为true,执行not in
SQL> conn chf/oracle Connected. SQL> set autot trace SQL> set timing on SQL> set lines 150 SQL> set pages 1000 SQL> select count(*) from t_xifenfei1 where object_id not in(select object_id from t_xifenfei); Elapsed: 00:00:00.09 Execution Plan ---------------------------------------------------------- Plan hash value: 4048525918 ---------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ---------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 10 | 688 (1)| 00:00:09 | | 1 | SORT AGGREGATE | | 1 | 10 | | | |* 2 | HASH JOIN RIGHT ANTI NA| | 1137 | 11370 | 688 (1)| 00:00:09 | | 3 | TABLE ACCESS FULL | T_XIFENFEI | 85341 | 416K| 344 (1)| 00:00:05 | | 4 | TABLE ACCESS FULL | T_XIFENFEI1 | 86260 | 421K| 344 (1)| 00:00:05 | ---------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("OBJECT_ID"="OBJECT_ID") Statistics ---------------------------------------------------------- 1 recursive calls 0 db block gets 2472 consistent gets 0 physical reads 0 redo size 527 bytes sent via SQL*Net to client 520 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed
_optimizer_null_aware_antijoin为false,执行not in
SQL> alter session set "_optimizer_null_aware_antijoin"=false; Session altered. Elapsed: 00:00:00.00 SQL> select count(*) from t_xifenfei1 where object_id not in(select object_id from t_xifenfei); Elapsed: 00:02:29.64 Execution Plan ---------------------------------------------------------- Plan hash value: 2503880249 ----------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ----------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 5 | 25M (1)| 86:20:57 | | 1 | SORT AGGREGATE | | 1 | 5 | | | |* 2 | FILTER | | | | | | | 3 | TABLE ACCESS FULL| T_XIFENFEI1 | 86260 | 421K| 344 (1)| 00:00:05 | |* 4 | TABLE ACCESS FULL| T_XIFENFEI | 1 | 5 | 344 (1)| 00:00:05 | ----------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - filter( NOT EXISTS (SELECT 0 FROM "T_XIFENFEI" "T_XIFENFEI" WHERE LNNVL("OBJECT_ID"<>:B1))) 4 - filter(LNNVL("OBJECT_ID"<>:B1)) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 52982891 consistent gets 0 physical reads 0 redo size 527 bytes sent via SQL*Net to client 520 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed
这里很明显,当 _optimizer_null_aware_antijoin为false的时候not in效率非常低(当in里面记录多,使用FILTER效率肯定低下).
_optimizer_null_aware_antijoin为false,执行not exists
SQL> alter session set "_optimizer_null_aware_antijoin"=false; Session altered. SQL>select count(*) from t_xifenfei1 b where not exists 2 (select 1 from t_xifenfei a where a.object_id=b.object_id); Elapsed: 00:00:00.07 Execution Plan ---------------------------------------------------------- Plan hash value: 2976307246 ------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 10 | 688 (1)| 00:00:09 | | 1 | SORT AGGREGATE | | 1 | 10 | | | |* 2 | HASH JOIN RIGHT ANTI| | 1137 | 11370 | 688 (1)| 00:00:09 | | 3 | TABLE ACCESS FULL | T_XIFENFEI | 85341 | 416K| 344 (1)| 00:00:05 | | 4 | TABLE ACCESS FULL | T_XIFENFEI1 | 86260 | 421K| 344 (1)| 00:00:05 | ------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("A"."OBJECT_ID"="B"."OBJECT_ID") Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 2472 consistent gets 0 physical reads 0 redo size 527 bytes sent via SQL*Net to client 520 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed
对于11g的版本可以通过_optimizer_null_aware_antijoin参数开启NULL-aware Anti join特性来提高not in的效率,对于11g以下版本可以通过not exists来提高效率