标签云
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,679)
- DB2 (22)
- MySQL (73)
- Oracle (1,541)
- Data Guard (52)
- EXADATA (8)
- GoldenGate (24)
- ORA-xxxxx (159)
- ORACLE 12C (72)
- ORACLE 18C (6)
- ORACLE 19C (14)
- ORACLE 21C (3)
- Oracle 23ai (7)
- Oracle ASM (67)
- Oracle Bug (8)
- Oracle RAC (52)
- Oracle 安全 (6)
- Oracle 开发 (28)
- Oracle 监听 (28)
- Oracle备份恢复 (563)
- 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)
-
最近发表
- 解决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
- ORA-01092 ORA-00604 ORA-01558故障处理
- ORA-65088: database open should be retried
- Oracle 19c异常恢复—ORA-01209/ORA-65088
标签归档:_unnest_subquery
使用_unnest_subquery优化sql
一个复杂的sql查询,使用了大量EXISTS和NOT EXISTS 关联导致sql执行效率低下,这里挑选出来最核心的部分进行演示
SQL> explain plan for select 2 a.aab034, a.aac001 3 from si_dp.ac01_ac02 a 4 where exists (select 1 5 from ic40 6 where aac001 = a.aac001 7 and aae045 <= '201803' 8 and aae120 = '0') 9 and not exists (select 1 10 from ic15 11 where aac001 = a.aac001 12 and aae002 <= '201803') 13 and not EXISTS (select aab001 14 from ab01 15 where aab019 in ('91', '93') 16 AND aab001 = a.aab001) 17 and exists (select 1 18 from ac13 19 where aac001 = a.aac001 20 and aae140 = '11' 21 and aae114 in ('0', '1') 22 and aae002 <= '201803') 23 AND EXISTS (SELECT 1 24 FROM AC13 25 WHERE AAC001 = A.AAC001 26 and aae140 = '11' 27 AND AAE143 = '02' 28 AND AAE003 < '201707' 29 AND AAE002 BETWEEN '201801' AND '201803' 30 and aae114 = '1') 31 AND not EXISTS (SELECT 1 32 FROM AC13 33 WHERE AAC001 = A.AAC001 34 and aae140 = '11' 35 AND AAE002 < '201801') 36 AND not EXISTS (SELECT 1 37 FROM ac02 38 WHERE AAC001 = A.AAC001 39 and aae140 = '11' 40 AND AAE036 < date '2018-1-1'); Explained. Elapsed: 00:00:00.36 SQL> select * from table (dbms_xplan.display); PLAN_TABLE_OUTPUT -------------------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| ----------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 202 | | 11172 (2)| | 1 | NESTED LOOPS SEMI | | 1 | 202 | | 11172 (2)| | 2 | NESTED LOOPS ANTI | | 1 | 175 | | 11168 (2)| | 3 | NESTED LOOPS SEMI | | 1 | 150 | | 11164 (2)| | 4 | NESTED LOOPS ANTI | | 1 | 126 | | 11160 (2)| | 5 | NESTED LOOPS SEMI | | 1 | 104 | | 11158 (2)| | 6 | NESTED LOOPS ANTI | | 1 | 67 | | 11145 (2)| | 7 | HASH JOIN ANTI | | 1 | 50 | 8640K| 11143 (2)| | 8 | TABLE ACCESS FULL | AC01_AC02 | 245K| 5755K| | 356 (2)| | 9 | TABLE ACCESS FULL | AC02 | 559K| 13M| | 9346 (2)| | 10 | TABLE ACCESS BY INDEX ROWID| AB01 | 2 | 34 | | 2 (0)| | 11 | INDEX UNIQUE SCAN | PK_AB01 | 1 | | | 1 (0)| | 12 | TABLE ACCESS BY INDEX ROWID | AC13 | 325K| 11M| | 13 (0)| | 13 | INDEX RANGE SCAN | I_AC13_AAE143 | 446 | | | 4 (0)| | 14 | INDEX RANGE SCAN | PK_IC15 | 1771K| 37M| | 2 (0)| | 15 | TABLE ACCESS BY INDEX ROWID | IC40 | 17M| 395M| | 4 (0)| | 16 | INDEX RANGE SCAN | PK_IC40 | 1 | | | 3 (0)| | 17 | TABLE ACCESS BY INDEX ROWID | AC13 | 51M| 1236M| | 4 (0)| | 18 | INDEX RANGE SCAN | RELATION_233112_FK | 3 | | | 3 (0)| | 19 | TABLE ACCESS BY INDEX ROWID | AC13 | 52M| 1350M| | 4 (0)| | 20 | INDEX RANGE SCAN | RELATION_233112_FK | 3 | | | 3 (0)| -----------------------------------------------------------------------------------------------------
这条sql,在一个10.2.0.3的系统中执行了十几个小时无法出结果,开发商反馈,该大部分客户的11.2的环境中,大概十几分钟出结果.从来没有遇到此类情况.让我们给他优化sql.看到这个sql,第一反应就是很可能大量的NESTED LOOPS效率低下,怀疑统计信息错误,结果收集完统计信息之后,执行计划依旧,我就在思考怎么调整sql,让其不这样大量嵌套执行.想起来的_unnest_subquery是控制子查询嵌套转换的,从9i开始默认为true,尝试设置为false测试.
SQL> alter session set "_unnest_subquery"=false; Session altered. Elapsed: 00:00:00.00 SQL> explain plan for select 2 a.aab034, a.aac001 3 from si_dp.ac01_ac02 a 4 where exists (select 1 5 from ic40 6 where aac001 = a.aac001 7 and aae045 <= '201803' 8 and aae120 = '0') 9 and not exists (select 1 10 from ic15 11 where aac001 = a.aac001 12 and aae002 <= '201803') 13 and not EXISTS (select aab001 14 from ab01 15 where aab019 in ('91', '93') 16 AND aab001 = a.aab001) 17 and exists (select 1 18 from ac13 19 where aac001 = a.aac001 20 and aae140 = '11' 21 and aae114 in ('0', '1') 22 and aae002 <= '201803') 23 AND EXISTS (SELECT 1 24 FROM AC13 25 WHERE AAC001 = A.AAC001 26 and aae140 = '11' 27 AND AAE143 = '02' 28 AND AAE003 < '201707' 29 AND AAE002 BETWEEN '201801' AND '201803' 30 and aae114 = '1') 31 AND not EXISTS (SELECT 1 32 FROM AC13 33 WHERE AAC001 = A.AAC001 34 and aae140 = '11' 35 AND AAE002 < '201801') 36 AND not EXISTS (SELECT 1 37 FROM ac02 38 WHERE AAC001 = A.AAC001 39 and aae140 = '11' 40 AND AAE036 < date '2018-1-1'); Explained. Elapsed: 00:00:00.07 SQL> select * from table (dbms_xplan.display); PLAN_TABLE_OUTPUT ----------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| ----------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 185K| 19M| | 2991K (2)| | 1 | FILTER | | | | | | | 2 | HASH JOIN RIGHT SEMI | | 185K| 19M| 16M| 758K (3)| | 3 | TABLE ACCESS BY INDEX ROWID| AC13 | 353K| 12M| | 4556 (1)| | 4 | INDEX SKIP SCAN | I_AC13_AAB001 | 23608 | | | 2287 (1)| | 5 | HASH JOIN SEMI | | 201K| 14M| 11M| 751K (3)| | 6 | HASH JOIN SEMI | | 201K| 9452K| 8640K| 123K (3)| | 7 | TABLE ACCESS FULL | AC01_AC02 | 245K| 5755K| | 357 (2)| | 8 | TABLE ACCESS FULL | IC40 | 21M| 481M| | 86122 (3)| | 9 | TABLE ACCESS FULL | AC13 | 52M| 1350M| | 530K (3)| | 10 | INDEX RANGE SCAN | PK_IC15 | 2 | 44 | | 3 (0)| | 11 | VIEW | index$_join$_009 | 1 | 17 | | 3 (34)| | 12 | HASH JOIN | | | | | | | 13 | INDEX RANGE SCAN | PK_AB01 | 1 | 17 | | 2 (0)| | 14 | INLIST ITERATOR | | | | | | | 15 | INDEX RANGE SCAN | IDX_AB01_AAB019 | 1 | 17 | | 8 (0)| | 16 | TABLE ACCESS BY INDEX ROWID | AC13 | 2 | 50 | | 5 (0)| | 17 | INDEX RANGE SCAN | I_AC13_SEARCH | 152 | | | 4 (0)| | 18 | TABLE ACCESS BY INDEX ROWID | AC02 | 1 | 26 | | 4 (0)| | 19 | INDEX RANGE SCAN | PK_AC02 | 1 | | | 3 (0)| -----------------------------------------------------------------------------------------------
让开发设置该参数,然后执行sql,结果3分钟不到出结果,非常圆满完成任务.该sql还有进一步优化空间,但是考虑到已经满足要求,不再折腾.