Connor and Chris will both be at AI World from October 12 to October 17 , the premier Oracle conference of 2025. If you're in Vegas, please come say Hi or pop into our sessions
Thanks for the question, karthick.
Asked: January 22, 2009 - 8:53 am UTC
Last updated: November 15, 2011 - 8:41 am UTC
Version: 10g R2
Viewed 10K+ times! This question is
SQL> create table t 2 as 3 select * 4 from all_objects 5 / Table created. SQL> create index t_idx on t(object_type) 2 / Index created. SQL> exec dbms_stats.gather_table_stats(user,'T',cascade=>true) PL/SQL procedure successfully completed. SQL> delete from plan_table 2 / 10 rows deleted. SQL> explain plan 2 for 3 select * from t where object_type like '%TABLE%' 4 / Explained. SQL> select * from table(dbms_xplan.display) 2 / PLAN_TABLE_OUTPUT ----------------------------------------------------------------------------------------------- Plan hash value: 1601196873 -------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | -------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 5823 | 511K| 358 (3)| 00:00:05 | |* 1 | TABLE ACCESS FULL| T | 5823 | 511K| 358 (3)| 00:00:05 | -------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- PLAN_TABLE_OUTPUT ----------------------------------------------------------------------------------------------- 1 - filter("OBJECT_TYPE" LIKE '%TABLE%') 13 rows selected.
Steve C., January 22, 2009 - 5:09 pm UTC
select distinct first_nm from person where first_nm like '%EV%';
A reader, November 14, 2011 - 8:23 am UTC
Reader, February 27, 2015 - 3:16 pm UTC
FULL table scan does not make sense in the following situation : - We have a 15G table with about 40 columns - One of the columns called NAME is indexed and the index size is 800M - The following shows that an INDEX FULL scan requires almost 8 times less I/O then a FULL TABLE scan. SQL> SELECT NAME, LISTING_ID FROM DPF.VBLIF_SO_HISTO WHERE NAME LIKE '%Bess Tank Line%' ; NAME L ------------------------------ - Bess Tank Line 1 row selected. Execution Plan ---------------------------------------------------------- Plan hash value: 2266721468 ------------------------------------------------------------------------------------ | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 1 | 2006 | 430K (1)| 00:00:17 | |* 1 | TABLE ACCESS FULL| VBLIF_SO_HISTO | 1 | 2006 | 430K (1)| 00:00:17 | ------------------------------------------------------------------------------------ Predicate Information (identified by operation id): --------------------------------------------------- 1 - filter("NAME" IS NOT NULL AND "NAME" LIKE '%Bess Tank Line%') Statistics ---------------------------------------------------------- 795 recursive calls 0 db block gets 1183985 consistent gets 1183829 physical reads 0 redo size 428 bytes sent via SQL*Net to client 492 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 22 sorts (memory) 0 sorts (disk) 1 rows processed SQL> SELECT /*+ index (VBLIF_SO_HISTO VBLIF_SO_HISTO_NAME) */ 2 NAME, LISTING_ID 3 FROM DPF.VBLIF_SO_HISTO 4 WHERE NAME LIKE '%Bess Tank Line%' ; NAME L ------------------------------ - Bess Tank Line 1 row selected. Execution Plan ---------------------------------------------------------- Plan hash value: 3012449389 ----------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ----------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 2006 | 2055K (1)| 00:01:21 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED| VBLIF_SO_HISTO | 1 | 2006 | 2055K (1)| 00:01:21 | |* 2 | INDEX FULL SCAN | VBLIF_SO_HISTO_NAME | 2192K| | 152K (1)| 00:00:06 | ----------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - filter("NAME" IS NOT NULL AND "NAME" LIKE '%Bess Tank Line%') Statistics ---------------------------------------------------------- 1 recursive calls 0 db block gets 151538 consistent gets 151536 physical reads 0 redo size 428 bytes sent via SQL*Net to client 492 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed I don't see why we have to use a hint ; the optimizer should be able to realize that. Thanks
Check out more PL/SQL tutorials on our LiveSQL tool.
PL/SQL reference manual from the Oracle documentation library