With Oracle 9i, the Cost-Based Optimizer (CBO) is equipped with many useful features, one of them is “Index skip scan“. In previous releases a composite index could only be used if the first column, the leading edge, of the index was referenced in the WHERE clause of a statement. In Oracle 9i this restriction is removed because the optimizer can perform skip scans to retrieve rowids for values that do not use the prefix. This means even if you have a composite index on more than one column and you use the non-prefix column alone in your SQL, it may still use index. (Earlier I use to think that it will not use index :)) Its not always guaranteed that the Index Skip Scan will be used, this is because Cost-Based Optimizer (CBO) will calculate the cost of using the index and if it is more than that of full table scan, then it may not use index. This approach is advantageous because:
Index skip scan works differently from a normal index (range) scan. A normal range scan works from top to bottom first and then move horizontal. But a Skip scan includes several range scans in it. Since the query lacks the leading column it will rewrite the query into smaller queries and each doing a range scan. Consider following example where we create a test
table and create index on first two columns a
and b
. Also we put some dummy data inside test
table. See how Index is getting selected when we execute select
statement with column b
in where
clause.
CREATE TABLE test (a NUMBER, b NUMBER, c NUMBER);
Code language: SQL (Structured Query Language) (sql)
Table created.
CREATE INDEX test_i
ON test (a, b);
Code language: SQL (Structured Query Language) (sql)
Index created.
BEGIN
FOR i IN 1 .. 100000
LOOP
INSERT INTO test
VALUES (MOD (i, 5), i, 100);
END LOOP;
COMMIT;
END;
/
Code language: SQL (Structured Query Language) (sql)
PL/SQL procedure successfully completed.
Code language: SQL (Structured Query Language) (sql)exec dbms_stats.gather_table_stats ( ownname => 'gauravsoni', tabname => 'test', cascade => true );
PL/SQL procedure successfully completed.
set autotrace trace exp
Code language: SQL (Structured Query Language) (sql)
SELECT *
FROM test
WHERE b = 95267;
Code language: SQL (Structured Query Language) (sql)
0
SELECT STATEMENT Optimizer=ALL_ROWS (Cost=22 Card=1 Bytes=10)
1 0
TABLE ACCESS (BY INDEX ROWID) OF 'TEST' (TABLE) (Cost=22 Card=1 Bytes=10)
2 1
INDEX (SKIP SCAN) OF 'TEST_I' (INDEX) (Cost=21 Card=1)
Code language: SQL (Structured Query Language) (sql)
I above example, "select * from test where b=95267"
was broken down to several small range scan queries. It was effectively equivalent to following:
SELECT *
FROM test
WHERE a = 0 AND b = 95267
UNION
SELECT *
FROM test
WHERE a = 1 AND b = 95267
UNION
SELECT *
FROM test
WHERE a = 2 AND b = 95267
UNION
SELECT *
FROM test
WHERE a = 3 AND b = 95267
UNION
SELECT *
FROM test
WHERE a = 4 AND b = 95267;
Code language: SQL (Structured Query Language) (sql)
In concrete, saying that skip scan is not as efficient as normal “single range scan” is correct. But yet saves some disk space and overhead of maintaining another index.
Oracle Documentation on Index Skip Scan
Java URL Encoder/Decoder Example - In this tutorial we will see how to URL encode/decode…
Show Multiple Examples in OpenAPI - OpenAPI (aka Swagger) Specifications has become a defecto standard…
Local WordPress using Docker - Running a local WordPress development environment is crucial for testing…
1. JWT Token Overview JSON Web Token (JWT) is an open standard defines a compact…
GraphQL Subscription provides a great way of building real-time API. In this tutorial we will…
1. Overview Spring Boot Webflux DynamoDB Integration tests - In this tutorial we will see…
View Comments
Good Article. The usage of index skip scan depends on the cardinality of the leading column. When the cardinality is low, means there are few distinct values in the leading column, index skip scan comes into effect. However as you have described it is not much efficient compared to other index scans like range scan.
good article
Thank you so much for explaination