标签云
asm恢复 bbed bootstrap$ dul In Memory kcbzib_kcrsds_1 kccpb_sanity_check_2 MySQL恢复 ORA-00312 ORA-00607 ORA-00704 ORA-00742 ORA-01110 ORA-01555 ORA-01578 ORA-01595 ORA-08103 ORA-600 2131 ORA-600 2662 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)
- 操作系统 (103)
- 数据库 (1,759)
- DB2 (22)
- MySQL (76)
- Oracle (1,601)
- Data Guard (52)
- EXADATA (8)
- GoldenGate (24)
- ORA-xxxxx (165)
- ORACLE 12C (72)
- ORACLE 18C (6)
- ORACLE 19C (15)
- ORACLE 21C (3)
- Oracle 23ai (8)
- Oracle ASM (69)
- Oracle Bug (8)
- Oracle RAC (54)
- Oracle 安全 (6)
- Oracle 开发 (28)
- Oracle 监听 (28)
- Oracle备份恢复 (588)
- Oracle安装升级 (96)
- Oracle性能优化 (62)
- 专题索引 (5)
- 勒索恢复 (85)
- PostgreSQL (30)
- pdu工具 (6)
- PostgreSQL恢复 (9)
- SQL Server (32)
- SQL Server恢复 (13)
- TimesTen (7)
- 达梦数据库 (3)
- 达梦恢复 (1)
- 生活娱乐 (2)
- 至理名言 (11)
- 虚拟化 (2)
- VMware (2)
- 软件开发 (39)
- Asp.Net (9)
- JavaScript (12)
- PHP (2)
- 小工具 (22)
-
最近发表
- linux环境oracle数据库被文件系统勒索加密为.babyk扩展名溯源
- ORA-600 ksvworkmsgalloc: bad reaper
- ORA-600 krccfl_chunk故障处理
- Oracle Recovery Tools恢复案例总结—202505
- ORA-600 kddummy_blkchk 数据库循环重启
- 记录一次asm disk加入到vg通过恢复直接open库的案例
- CHECKDB 发现了 N 个分配错误和 M 个一致性错误
- 达梦数据库dm.ctl文件异常恢复
- Oracle Recovery Tools修复ORA-00742、ORA-600 ktbair2: illegal inheritance故障
- 可能是 tempdb 空间用尽或某个系统表不一致故障处理
- 11.2.0.4库中遇到ORA-600 kcratr_nab_less_than_odr报错
- [MY-013183] [InnoDB] Assertion failure故障处理
- Oracle 19c 202504补丁(RUs+OJVM)-19.27
- Oracle Recovery Tools修复ORA-600 6101/kdxlin:psno out of range故障
- pdu完美支持金仓数据库恢复(KingbaseES)
- 虚拟机故障引起ORA-00310 ORA-00334故障处理
- pg创建gbk字符集库
- PostgreSQL运行日志管理
- ora-600 kdsgrp1 错误描述
- GAM、SGAM 或 PFS 页上存在页错误处理
标签归档:connect_by_filtering
11g中 connect by 语句执行计划改变
从10.2.0.3升级到11.2.0.4的朋友,如果细心会发现,以下sql在11.2.0.4中执行效率变低(该sql主要是获取连接用户获取权限信息)
select privilege#,level from sysauth$ connect by grantee#=prior privilege# and privilege#>0 start with grantee#=:1 and privilege#>0
如果你接触是Oracle版本比较多,而且还比较细心,你可能会进一步发现在11.2.0.2中该条sql是:select /*+ connect_by_filtering */ privilege#, level from sysauth$ connect by grantee#=prior privilege# and privilege#>0 start with grantee#=:1 and privilege#>0 也就是说使用了/*+ connect_by_filtering */提示.我这里通过简单测试说明问题.
在11.2.0.4环境中
14:16:19 SQL> set autot trace exp stat 14:16:20 SQL> set time on 14:16:20 SQL> set timing on 14:16:20 SQL> var a1 number; 14:16:20 SQL> exec :a1:=6; PL/SQL 过程已成功完成。 已用时间: 00: 00: 00.00 14:16:20 SQL> select privilege#,level from sysauth$ connect by grantee#=prior 14:16:20 SQL> privilege# and privilege#>0 start with grantee#=:a1 and privilege#>0 14:16:22 SQL> / 已用时间: 00: 00: 00.01 执行计划 ---------------------------------------------------------- Plan hash value: 2624122540 ------------------------------------------------------------------------------------------------------ | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ------------------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 7 | 182 | 3 (34)| 00:00:01 | |* 1 | CONNECT BY NO FILTERING WITH START-WITH| | | | | | | 2 | INDEX FAST FULL SCAN | I_SYSAUTH1 | 618 | 4944 | 2 (0)| 00:00:01 | ------------------------------------------------------------------------------------------------------ Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("GRANTEE#"=PRIOR "PRIVILEGE#") filter("PRIVILEGE#">0 AND "GRANTEE#"=TO_NUMBER(:A1) AND "PRIVILEGE#">0) 统计信息 ---------------------------------------------------------- 1 recursive calls 0 db block gets 7 consistent gets 0 physical reads 0 redo size 599 bytes sent via SQL*Net to client 520 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 2 sorts (memory) 0 sorts (disk) 1 rows processed
这里可以看出来这里使用的执行计划使用了CONNECT BY NO FILTERING WITH START-WITH,逻辑读为7.
10.2.0.3环境中
14:32:57 SQL> set lines 150 14:33:00 SQL> set autot trace exp stat 14:33:01 SQL> set time on 14:33:01 SQL> set timing on 14:33:01 SQL> var a1 number; 14:33:01 SQL> exec :a1:=6; PL/SQL procedure successfully completed. Elapsed: 00:00:00.00 14:33:01 SQL> select privilege#,level from sysauth$ connect by grantee#=prior 14:33:01 SQL> privilege# and privilege#>0 start with grantee#=:a1 and privilege#>0 ; Elapsed: 00:00:00.00 Execution Plan ---------------------------------------------------------- Plan hash value: 2620769641 ---------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ---------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 3 | 24 | 2 (0)| 00:00:01 | |* 1 | CONNECT BY WITH FILTERING| | | | | | |* 2 | INDEX RANGE SCAN | I_SYSAUTH1 | 3 | 24 | 2 (0)| 00:00:01 | | 3 | NESTED LOOPS | | | | | | | 4 | CONNECT BY PUMP | | | | | | |* 5 | INDEX RANGE SCAN | I_SYSAUTH1 | 3 | 24 | 2 (0)| 00:00:01 | ---------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("GRANTEE#"=PRIOR "PRIVILEGE#") filter("PRIVILEGE#">0) 2 - access("GRANTEE#"=TO_NUMBER(:A1) AND "PRIVILEGE#">0) 5 - access("GRANTEE#"=PRIOR "PRIVILEGE#" AND "PRIVILEGE#">0) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 4 consistent gets 0 physical reads 0 redo size 583 bytes sent via SQL*Net to client 492 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 3 sorts (memory) 0 sorts (disk) 1 rows processed
这里执行计划使用的为CONNECT BY WITH FILTERING,而且逻辑读为4,对于这个sql来说,使用CONNECT BY WITH FILTERING执行效率更高.
这里可以很明显的看到:connect by查询的执行计划从10g的CONNECT BY WITH FILTERING变为了11g中的CONNECT BY NO FILTERING WITH SW (UNIQUE),从而使得执行计划发生改变。但是Oracle一般有个特性,就是当引入新特性之时,一般都会伴随隐含参数或者event来屏蔽新特性.这里也例外,我们可以通过”_optimizer_connect_by_elim_dups” = false和”_connect_by_use_union_all” = “old_plan_mode”来屏蔽11g中关于connect by执行计划的改变,使得执行计划恢复到10G的CONNECT BY WITH FILTERING方式
14:30:45 SQL> alter session set "_optimizer_connect_by_elim_dups" = false; 会话已更改。 已用时间: 00: 00: 00.00 14:30:46 SQL> alter session set "_connect_by_use_union_all" = "old_plan_mode"; 会话已更改。 已用时间: 00: 00: 00.00 14:30:46 SQL> set autot trace exp stat 14:30:46 SQL> set time on 14:30:46 SQL> set timing on 14:30:46 SQL> var a1 number; 14:30:46 SQL> exec :a1:=6; PL/SQL 过程已成功完成。 已用时间: 00: 00: 00.00 14:30:46 SQL> select privilege#,level from sysauth$ connect by grantee#=prior 14:30:46 SQL> privilege# and privilege#>0 start with grantee#=:a1 and privilege#>0 ; 已用时间: 00: 00: 00.01 执行计划 ---------------------------------------------------------- Plan hash value: 2620769641 ---------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ---------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 2 | 16 | 2 (0)| 00:00:01 | |* 1 | CONNECT BY WITH FILTERING| | | | | | |* 2 | INDEX RANGE SCAN | I_SYSAUTH1 | 2 | 16 | 2 (0)| 00:00:01 | | 3 | NESTED LOOPS | | | | | | | 4 | CONNECT BY PUMP | | | | | | |* 5 | INDEX RANGE SCAN | I_SYSAUTH1 | 2 | 16 | 2 (0)| 00:00:01 | ---------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("GRANTEE#"=PRIOR "PRIVILEGE#") filter("PRIVILEGE#">0) 2 - access("GRANTEE#"=TO_NUMBER(:A1) AND "PRIVILEGE#">0) 5 - access("GRANTEE#"=PRIOR "PRIVILEGE#" AND "PRIVILEGE#">0) 统计信息 ---------------------------------------------------------- 1 recursive calls 0 db block gets 4 consistent gets 0 physical reads 0 redo size 599 bytes sent via SQL*Net to client 520 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 3 sorts (memory) 0 sorts (disk) 1 rows processed
11.2.0.2中也许是考虑到connect by 不够成熟,因此使用了hint /*+ connect_by_filtering */ 来固定执行计划
14:22:09 SQL> select /*+ connect_by_filtering */ privilege#,level from sysauth$ connect by grantee#=prior 14:22:09 SQL> privilege# and privilege#>0 start with grantee#=:a1 and privilege#>0 14:22:10 SQL> / 已用时间: 00: 00: 00.00 执行计划 ---------------------------------------------------------- Plan hash value: 2620769641 ---------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ---------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 7 | 182 | 8 (25)| 00:00:01 | |* 1 | CONNECT BY WITH FILTERING| | | | | | |* 2 | INDEX RANGE SCAN | I_SYSAUTH1 | 2 | 16 | 2 (0)| 00:00:01 | | 3 | NESTED LOOPS | | 5 | 105 | 4 (0)| 00:00:01 | | 4 | CONNECT BY PUMP | | | | | | |* 5 | INDEX RANGE SCAN | I_SYSAUTH1 | 2 | 16 | 1 (0)| 00:00:01 | ---------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("GRANTEE#"=PRIOR "PRIVILEGE#") filter("PRIVILEGE#">0) 2 - access("GRANTEE#"=TO_NUMBER(:A1) AND "PRIVILEGE#">0) 5 - access("GRANTEE#"="connect$_by$_pump$_002"."prior privilege# " AND "PRIVILEGE#">0) 统计信息 ---------------------------------------------------------- 1 recursive calls 0 db block gets 4 consistent gets 0 physical reads 0 redo size 599 bytes sent via SQL*Net to client 520 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 3 sorts (memory) 0 sorts (disk) 1 rows processed
CONNECT BY NO FILTERING WITH SW (UNIQUE)和CONNECT BY WITH FILTERING,没有明显的优劣之分,只有在特定的情况下,进行了实际的测试,选择合适自己的sql的执行计划