标签云
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,680)
- DB2 (22)
- MySQL (73)
- Oracle (1,542)
- 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备份恢复 (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)
-
最近发表
- 手工删除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
- ORA-01092 ORA-00604 ORA-01558故障处理
- ORA-65088: database open should be retried
标签归档:is null 优化
含is null sql语句优化
原sql语句与执行计划
SQL> set autot trace SQL> WITH AL AS (SELECT * FROM XIFENFEI_LOG WHERE CLEAR_TIME IS NULL) 2 SELECT SWP.ID SWP_ID, AL.* FROM AL FULL OUTER JOIN XIFENFEI_LOG_SWAP SWP ON SWP.ID = AL.ID; 54 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 888046630 ---------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ---------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 24 | 11064 | 24658 (2)| 00:04:56 | | 1 | TEMP TABLE TRANSFORMATION | | | | | | | 2 | LOAD AS SELECT | | | | | | |* 3 | TABLE ACCESS FULL | XIFENFEI_LOG | 23 | 2576 | 24652 (2)| 00:04:56 | | 4 | VIEW | | 24 | 11064 | 6 (17)| 00:00:01 | | 5 | UNION-ALL | | | | | | | 6 | NESTED LOOPS OUTER | | 23 | 10465 | 2 (0)| 00:00:01 | | 7 | VIEW | | 23 | 10304 | 2 (0)| 00:00:01 | | 8 | TABLE ACCESS FULL | SYS_TEMP_0FD9D6605_51B4E691 | 23 | 2576 | 2 (0)| 00:00:01 | |* 9 | INDEX UNIQUE SCAN | XIFENFEI_LOG_SWP_PK | 1 | 7 | 0 (0)| 00:00:01 | |* 10 | HASH JOIN ANTI | | 1 | 20 | 4 (25)| 00:00:01 | | 11 | INDEX FULL SCAN | XIFENFEI_LOG_SWP_PK | 20 | 140 | 1 (0)| 00:00:01 | | 12 | VIEW | | 23 | 299 | 2 (0)| 00:00:01 | | 13 | TABLE ACCESS FULL | SYS_TEMP_0FD9D6605_51B4E691 | 23 | 2576 | 2 (0)| 00:00:01 | ---------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 3 - filter("CLEAR_TIME" IS NULL) 9 - access("SWP"."ID"(+)="AL"."ID") 10 - access("SWP"."ID"="AL"."ID") Statistics ---------------------------------------------------------- 2 recursive calls 8 db block gets 111504 consistent gets 1 physical reads 692 redo size 8075 bytes sent via SQL*Net to client 502 bytes received via SQL*Net from client 5 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 54 rows processed
这里很明显占用资源多,执行时间长的都在XIFENFEI_LOG表的全表扫描上,而该表的where 条件是CLEAR_TIME is null.
分析CLEAR_TIME 列null值的分布
SQL> SELECT count(*) FROM XIFENFEI_LOG WHERE CLEAR_TIME IS NULL; COUNT(*) ---------- 48 SQL> SELECT count(*) FROM XIFENFEI_LOG WHERE CLEAR_TIME IS not NULL; COUNT(*) ---------- 6899211
通过这里分析可以知道,CLEAR_TIME is null的值非常少,如果能够创建一个index,取到CLEAR_TIME 列null的值,那效率将非常搞.但是有oracle index知识的人都知道,B树index是不包含null列,因此一般性index无法满足该需求.这里思考创建含常数的复合index,而且把CLEAR_TIME放在前面,因为后面的常数一定存在,因此CLEAR_TIME中含有null的记录也就包含在该复合index中.
创建含常数复合index
SQL> create index ind_XIFENFEI_LOG_null on XIFENFEI_LOG (CLEAR_TIME,0) online; Index created.
再次查看执行计划
SQL> WITH AL AS (SELECT * FROM XIFENFEI_LOG WHERE CLEAR_TIME IS NULL) 2 SELECT SWP.ID SWP_ID, AL.* FROM AL FULL OUTER JOIN XIFENFEI_LOG_SWAP SWP ON SWP.ID = AL.ID; 50 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 2359331571 ------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 24 | 11064 | 25 (4)| 00:00:01 | | 1 | TEMP TABLE TRANSFORMATION | | | | | | | 2 | LOAD AS SELECT | | | | | | | 3 | TABLE ACCESS BY INDEX ROWID| XIFENFEI_LOG | 23 | 2576 | 19 (0)| 00:00:01 | |* 4 | INDEX RANGE SCAN | IND_XIFENFEI_LOG_NULL | 23 | | 3 (0)| 00:00:01 | | 5 | VIEW | | 24 | 11064 | 6 (17)| 00:00:01 | | 6 | UNION-ALL | | | | | | | 7 | NESTED LOOPS OUTER | | 23 | 10465 | 2 (0)| 00:00:01 | | 8 | VIEW | | 23 | 10304 | 2 (0)| 00:00:01 | | 9 | TABLE ACCESS FULL | SYS_TEMP_0FD9D660D_51B4E691 | 23 | 2576 | 2 (0)| 00:00:01 | |* 10 | INDEX UNIQUE SCAN | XIFENFEI_LOG_SWP_PK | 1 | 7 | 0 (0)| 00:00:01 | |* 11 | HASH JOIN ANTI | | 1 | 20 | 4 (25)| 00:00:01 | | 12 | INDEX FULL SCAN | XIFENFEI_LOG_SWP_PK | 20 | 140 | 1 (0)| 00:00:01 | | 13 | VIEW | | 23 | 299 | 2 (0)| 00:00:01 | | 14 | TABLE ACCESS FULL | SYS_TEMP_0FD9D660D_51B4E691 | 23 | 2576 | 2 (0)| 00:00:01 | ------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 4 - access("CLEAR_TIME" IS NULL) 10 - access("SWP"."ID"(+)="AL"."ID") 11 - access("SWP"."ID"="AL"."ID") Statistics ---------------------------------------------------------- 2 recursive calls 8 db block gets 33 consistent gets 1 physical reads 648 redo size 7688 bytes sent via SQL*Net to client 502 bytes received via SQL*Net from client 5 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 50 rows processed
这里可以发现,该sql使用了创建的含常数的复合index,sql执行时间从4分56秒,提高到现在的1秒钟,逻辑读从当初的111504减小到现在的33,巧用含常数的复合索引使得sql执行效率极大提高.