Most execution plans can be interpreted by following few basic rules (in TOP, Chapter 6, I provide such a list of rules). Nevertheless, there are some special cases. One of them is when an index scan, in addition to the access predicate, has a filter predicate applying a subquery.
The following execution plan, taken from Enterprise Manager 11.2, is an example (click on the image to increase its size):
Notes:
- According to the order column the first operation being executed is the scan of the
I2
index. Unfortunately this is wrong. In fact the first operation being executed is the scan of theI1
index. This is a bug in Enterprise Manager. I wanted to show you this example to demonstrate that not only for us it might be difficult to correctly interpret an execution plan ;-) - The filter predicate
IS NOT NULL
is also wrong. This is not a bug, however. It is a limitation in the current implementation. The problem is that in some cases theV$SQL_PLAN
andV$SQL_PLAN_STATISTICS_ALL
views are not able to show all the necessary details.
Without seeing the query on which this execution plan is based, it is not obvious at all to know what’s going on. So, here is the query:
SELECT * FROM t1 WHERE n1 = 8 AND n2 IN (SELECT t2.n1 FROM t2, t3 WHERE t2.id = t3.id AND t3.n1 = 8)
Based on the query it is essential to point out that the access predicate "T2"."N1"=:B1
cannot be evaluated and, therefore, the scan of the I2
index cannot be carried out, without having a value passed through the B1 bind variable. In other words, without knowing the value of T1.N2
.
To describe how this execution plan is carried out, let’s have a look to the information provided by the DBMS_XPLAN.DISPLAY
function (which does not expose the limitation related to the filter predicate).
----------------------------------------------- | Id | Operation | Name | ----------------------------------------------- | 0 | SELECT STATEMENT | | | 1 | TABLE ACCESS BY INDEX ROWID | T1 | |* 2 | INDEX RANGE SCAN | I1 | | 3 | NESTED LOOPS | | | 4 | TABLE ACCESS BY INDEX ROWID| T2 | |* 5 | INDEX RANGE SCAN | I2 | |* 6 | TABLE ACCESS BY INDEX ROWID| T3 | |* 7 | INDEX RANGE SCAN | I3 | ----------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("N1"=8) filter( EXISTS (SELECT /*+ LEADING ("T2" "T3") USE_NL ("T3") INDEX ("T3" "I3") INDEX_RS_ASC ("T2" "I2") */ 0 FROM "T3" "T3","T2" "T2" WHERE "T2"."N1"=:B1 AND "T3"."N1"=8 AND "T2"."ID"="T3"."ID")) 5 - access("T2"."N1"=:B1) 6 - filter("T2"."ID"="T3"."ID") 7 - access("T3"."N1"=8)
The operations are carried out as follows:
- Operation 2 applies the access predicate
"N1"=8
by scanning theI1
index. - For each key returned by the previous scan, the subquery is executed once. Note that the subquery carries out a nested loop. While the outer loop accesses the
T2
table, the inner loop accesses theT3
table. - The first operation of the outer loop is operation 5. It applies the access predicate
"T2"."N1"=:B1
by scanning theI2
index. Based on the rowid returned by the index access theT2
table is accessed (operation 4). - For each row returned by the outer loop, the inner loop is executed once. The first operation of the inner loop is operation 7. It applies the access predicate
"T3"."N1"=8
by scanning theI3
index. Based on the rowid returned by the index access theT3
table is accessed (operation 6) and the filter predicate"T2"."ID"="T3"."ID"
(the join condition) is applied. By the way, it is interesting to notice that, contrary to the join condition is not applied as an access predicate, as it usually happens. - If the subquery returns a row, the rowid returned by operation 2 can be used to access the
T1
table (operation 1). The row extracted from this operation is sent to the caller.
All in all, this is a very special execution plan…
In summary, be careful when you see an index scan with a filter predicate applying a subquery. The execution plan might not be carried out as you expect at first sight. It is also essential to point out that in such a case the predicate information is essential to fully understand what’s going on.
Hi Christian,
Thanks a lot for this precision. From now and on I will make attention to explain plans showing an index scan with both access and filter predicate applying a subquery.
I often also see explain plans showing a A-Time of the parent operation being less than the sum of A-Time of its corresponding child operations as for example in the following example taken from an otn thread
https://forums.oracle.com/forums/thread.jspa?messageID=10167734�
How could this be possible ?
Best Regards
Mohamed Houri
Hi Mohamed
Runtime statistics generated with gather_plan_statistics are based on sampling. Hence, they are not always accurate.
HTH
Chris
[…] interesting little defect in Enterprise Manager a little while ago – it doesn’t always know how to interpret execution plans. The problem appears in Christians’ example when a filter subquery predicate is applied […]
[…] rule is not applicable. Among those cases, I know two : the “constant subquery” and index scan with a filter predicate applying a subquery 0.000000 0.000000 Share this:EmailPrintLike this:Like Loading… Leave a […]