Since Christmas I have been asked to investigate two different “failures to use Smart Scan”. It turns out they both fell into the same little known restriction on the use of Direct Read. Smart Scan critically depends on Direct Read in order to read the synthetic output blocks into private buffers in PGA so with Direct Read disabled Smart Scan is also disabled. In these two cases the restriction is on using Direct Read on Serial Recursive queries.
Case 1: Materialized View Refresh
A customer asked me to investigate why his MView refresh was running slowly and was failing to use Smart Scan. He had used 'trace[NSMTIO] disk=highest'
which showed the cause as:
Direct Read for serial qry: disabled(::recursive_call::kctfsage:::)
but that didn’t help him understand why that was happening and the terse but accurate reply to their SR “force parallel query” didn’t help him understand why either. Good DBAs want to understand, not just have rules to apply and I appreciate that.
Case 2: From Containers() clause
The From Containers()
clause is a less well known feature of Containers databases that lets you query a table in one or more a Pluggable databases. So, for example, if I connect to my CDB directly:
sqlplus sys/***********@cdb1_pdb0 as sysdba
SQL> show pdbs
CON_ID CON_NAME OPEN MODE RESTRICTED
---------- ------------------------------ ---------- ----------
2 PDB$SEED READ ONLY NO
3 CDB1_PDB1 READ WRITE NO
4 CDB1_PDB2 READ WRITE NO
SQL> select count(*) from obj$;
COUNT(*)
----------
75130
SQL> select count(*) from containers(obj$);
COUNT(*)
----------
226726
SQL> select count(*) from containers(obj$) where con_id=3;
COUNT(*)
----------
75671
Checking the NSMTIO tracing we see:
Direct Read for serial qry: disabled(::recursive_call::kctfsage::always DR:::)
The From Containers() clause scans a fixed table of PDBs, if there is a predicate on CON-ID only those PDBs that match the predicate and used otherwise all PDBs are used. A recursive query is issued against each PDB in the fixed table that meets the CON_ID clause and the query results are the Union All of the results from each matching PDB. Now if we force the query to run in parallel either by setting the session parameter to force parallel:
SQL> alter session force parallel QUERY parallel ;
or by using the Containers hint to pass the hint to each recursive query in turn:
SQL> select /*+ CONTAINERS(DEFAULT_PDB_HINT='PARALLEL 2') */ count(*) from containers(obj$) where con_id=3;
and check the tracing we see:
NSMTIO: NSMTIO:kkfdtsc:DirectRead:
Problem fixed.
How to get Smart Scan to engage
When Direct Read was introduced a short list of exceptions was added and one was on recursive serial queries, we have filed ER Bug 30905358 – FROM CONTAINERS() TABLE SCANS ARE NOT OFFLOADED to track the request to relax the restriction on recursive queries in a future release. In the meantime the correct solution is to add a parallel hint to the query or, if you are unable to modify the query, use the Force Parallel Query parameter.
—
Roger