By Clemens Bleile

To prepare a presentation about Multitenant Tuning I wanted to see the METHOD_OPT dbms_stats global preference of all my pluggable DBs. In this specific case I had 3 PBDs called pdb1, pdb2 and pdb3 in my CDB. For testing purposes I changed the global preference in pdb1 from its default ‘FOR ALL COLUMNS SIZE AUTO’ to ‘FOR ALL INDEXED COLUMNS SIZE AUTO’:

c##cbleile_adm@orclcdb@PDB1> exec dbms_stats.set_global_prefs('METHOD_OPT','FOR ALL INDEXED COLUMNS SIZE AUTO');
c##cbleile_adm@orclcdb@PDB1> select dbms_stats.get_prefs('METHOD_OPT') from dual;

DBMS_STATS.GET_PREFS('METHOD_OPT')
------------------------------------
FOR ALL INDEXED COLUMNS SIZE AUTO

Afterwards I ran my SQL with the containers clause from the root container:


c##cbleile_adm@orclcdb@CDB$ROOT> select con_id, dbms_stats.get_prefs('METHOD_OPT') method_opt from containers(dual);

    CON_ID METHOD_OPT
---------- --------------------------------
         1 FOR ALL COLUMNS SIZE AUTO
         3 FOR ALL COLUMNS SIZE AUTO
         4 FOR ALL COLUMNS SIZE AUTO
         5 FOR ALL COLUMNS SIZE AUTO

4 rows selected.

For CON_ID 3 I expected to see “FOR ALL INDEXED COLUMNS SIZE AUTO”. What is wrong here?

I actually got it to work with the following query:


c##cbleile_adm@orclcdb@CDB$ROOT> select con_id, method_opt from containers(select dbms_stats.get_prefs('METHOD_OPT') method_opt from dual);

    CON_ID METHOD_OPT
---------- ----------------------------------
         1 FOR ALL COLUMNS SIZE AUTO
         4 FOR ALL COLUMNS SIZE AUTO
         5 FOR ALL COLUMNS SIZE AUTO
         3 FOR ALL INDEXED COLUMNS SIZE AUTO

4 rows selected.

That is interesting. First of all I didn’t know that you can actually use SELECT-statements in the containers clause (according the syntax diagram it has to be a table or a view-name only) and secondly the function dbms_stats.get_prefs in the first example has obviously been called in the root container after getting the data.

I verified that last statement with a simple test by creating a function in all containers, which just returns the container id of the current container:


create or replace function c##cbleile_adm.show_con_id return number
as
conid number;
begin
     select to_number(sys_context('USERENV', 'CON_ID')) into conid from sys.dual;
     return conid;
  end;
/

And then the test:


c##cbleile_adm@orclcdb@CDB$ROOT> select con_id, show_con_id from containers(dual);

    CON_ID SHOW_CON_ID
---------- -----------
         1           1
         3           1
         4           1
         5           1

4 rows selected.

c##cbleile_adm@orclcdb@CDB$ROOT> select con_id, show_con_id from containers(select show_con_id from dual);

    CON_ID SHOW_CON_ID
---------- -----------
         4           4
         1           1
         3           3
         5           5

4 rows selected.

That proved that the function in the select-list of the first statement is actually called in the root container after getting the data from the PDBs.

Summary:
– be careful when running the containers-clause in a select-statement with a function in the select-list. You may get unexpected results.
– the syntax with a select-statement in the containers clause is interesting.

REMARK: Above tests have been performed with Oracle 19.6.