About me:Oracle ACE pro,optimistic,passionate and harmonious. Focus on ORACLE,MySQL and other database programming,peformance tuning,db design, j2ee,Linux/AIX,Architecture tech,etc
全部博文(169)
分类: Oracle
2022-04-12 10:46:03
SQL> DROP TABLE t; 表已删除。 SQL> CREATE TABLE t AS SELECT * FROM dba_objects; 表已创建。 SQL> INSERT INTO t SELECT * FROM t; 已创建73035行。 SQL> commit; 提交完成。 SQL> SELECT COUNT(*) FROM t; COUNT(*) ---------- 146070 --置1000条object_id为NULL SQL> UPDATE t SET object_id = NULL WHERE ROWNUM<1000; 已更新999行。 SQL> CREATE INDEX idx_t ON t(object_id); 索引已创建。 SQL> exec dbms_stats.gather_table_stats(ownname=>user,tabname=>'T',cascade=>true); PL/SQL 过程已成功完成。 |
SQL> set autotrace traceonly exp SQL> SELECT COUNT(*) FROM t WHERE object_id IS NULL; 执行计划 ---------------------------------------------------------- Plan hash value: 2966233522 --------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | --------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 5 | 588 (1)| 00:00:08 | | 1 | SORT AGGREGATE | | 1 | 5 | | | |* 2 | TABLE ACCESS FULL| T | 1023 | 5115 | 588 (1)| 00:00:08 | --------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - filter("OBJECT_ID" IS NULL) |
SQL> drop index idx_t; 索引已删除。 SQL> create index idx_t on t(nvl(object_id,0)); 索引已创建。 SQL> SELECT COUNT(*) FROM t WHERE nvl(object_id,0)=0; 执行计划 ---------------------------------------------------------- Plan hash value: 1500240790 --------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | --------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 13 | 1 (0)| 00:00:01 | | 1 | SORT AGGREGATE | | 1 | 13 | | | |* 2 | INDEX RANGE SCAN| IDX_T | 1461 | 18993 | 1 (0)| 00:00:01 | --------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access(NVL("OBJECT_ID",0)=0) |
SQL> drop index idx_t; 索引已删除。 SQL> create index idx_t on t(object_id,0); 索引已创建。 SQL> SELECT COUNT(*) FROM t WHERE object_id is null; 执行计划 ---------------------------------------------------------- Plan hash value: 1500240790 --------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | --------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 5 | 4 (0)| 00:00:01 | | 1 | SORT AGGREGATE | | 1 | 5 | | | |* 2 | INDEX RANGE SCAN| IDX_T | 1023 | 5115 | 4 (0)| 00:00:01 | --------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("OBJECT_ID" IS NULL) |