By Franck Pachot

.
Today I’ve presented SQL Plan Directives at the SOUG Romandie event. I had a question about the import/export of directives by Data Pump. The idea is that a lot of testing has been done on QA in order to validate the upgrade to 12c. A few directives had bad consequences (see Ludovico Caldara blog post for an example), then directives have been disabled. When going to production, they want to start with those directives disabled. Yes, they can be imported. We have to pack them into a staging table, import that table, and unpack them. It’s similar tho what we do with SQL Plan Baselines.

testcase: a PERMANENT SPD

I’m using the state of the demo in my presentation where I have a PERMANENT directive that I have disabled because I don’t want to do too much dynamic sampling.

SQL> show user
 USER is "DEMO"
 SQL> select table_name,num_rows,last_analyzed from user_tables;
 TABLE_NAME NUM_ROWS LAST_ANA
 -------------------- ---------- --------
 STGTAB
 DEMO_TABLE 1000 17:35:51
 SQL> select table_name,column_name,num_distinct,last_analyzed from user_tab_col_statistics;
 TABLE_NAME COLUMN_NAME NUM_DISTINCT LAST_ANA
 -------------------- ------------ ------------ --------
 DEMO_TABLE A 2 17:35:51
 DEMO_TABLE B 2 17:35:51
 DEMO_TABLE C 2 17:35:51
 DEMO_TABLE D 2 17:35:51
 DEMO_TABLE SYS_STSPJNMI 2 17:35:51
 SQL> select directive_id,state,created,last_modified,last_used,enabled,extract(notes,'//internal_state/text()') internal_state from dba_sql_plan_directives where directive_id in( select directive_id from dba_sql_plan_dir_objects where owner=user ) order by created;
 DIRECTIVE_ID STATE CREATED LAST_MOD LAST_USE ENABLED INTERNAL_
 ----------------------- ---------- -------- -------- -------- ------- ---------
 9456295843023884415 USABLE 17:35:45 18:07:16 18:07:16 NO PERMANENT

Pack directive

Datapump can export/import the table, the extended statistics and the statistics, but the SQL Plan Directives are not included. We have to pack then into a staging table in order to export/import that table and umpack it at the destination site.

SQL> exec dbms_spd.create_stgtab_directive('STGTAB');

PL/SQL procedure successfully completed.

SQL> select dbms_spd.pack_stgtab_directive('STGTAB',user,9456295843023884415) from dual;

DBMS_SPD.PACK_STGTAB_DIRECTIVE('STGTAB',USER,9456295843023884415)
-----------------------------------------------------------------
                                                                1

DataPump

Here I’ll import the DEMO table, and the STGTAB which contains the packed statistics, through a loopback database link, and import it to another schema: DEMO_SITE2

SQL> create database link LOOPBACK connect to demo identified by demo using '&_CONNECT_IDENTIFIER';
Database link created.

SQL> host impdp demo/demo@&_CONNECT_IDENTIFIER network_link=LOOPBACK tables="DEMO.DEMO_TABLE,DEMO.STGTAB" remap_schema='DEMO:DEMO_&&1';

Import: Release 12.1.0.1.0 - Production on Thu May 21 18:07:42 2015

Copyright (c) 1982, 2013, Oracle and/or its affiliates.  All rights reserved.

Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options
Starting "DEMO"."SYS_IMPORT_TABLE_01":  demo/********@//192.168.78.114/DEMO14 network_link=LOOPBACK tables=DEMO.DEMO_TABLE,DEMO.STGTAB remap_schema='DEMO:DEMO
_SITE2'
Estimate in progress using BLOCKS method...
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
Total estimation using BLOCKS method: 256 KB
Processing object type TABLE_EXPORT/TABLE/TABLE
. . imported "DEMO_SITE2"."STGTAB"                            6 rows
. . imported "DEMO_SITE2"."DEMO_TABLE"                     1000 rows
Processing object type TABLE_EXPORT/TABLE/INDEX/INDEX
Processing object type TABLE_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS
Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
Job "DEMO"."SYS_IMPORT_TABLE_01" successfully completed at Thu May 21 18:08:18 2015 elapsed 0 00:00:37

Check what is imported:

SQL> show user
USER is "DEMO_SITE2"
SQL> select table_name,num_rows,last_analyzed from user_tables;

TABLE_NAME             NUM_ROWS LAST_ANA
-------------------- ---------- --------
DEMO_TABLE                 1000 17:35:51
STGTAB

SQL> select table_name,column_name,num_distinct,last_analyzed from user_tab_col_statistics;

TABLE_NAME           COLUMN_NAME  NUM_DISTINCT LAST_ANA
-------------------- ------------ ------------ --------
DEMO_TABLE           A                       2 17:35:51
DEMO_TABLE           B                       2 17:35:51
DEMO_TABLE           C                       2 17:35:51
DEMO_TABLE           D                       2 17:35:51
DEMO_TABLE           SYS_STSPJNMI            2 17:35:51

SQL> select directive_id,type,state,created,last_modified,last_used,enabled,notes from dba_sql_plan_directives where directive_id in( select directive_id from dba_sql_plan_dir_objects where owner=user ) order by created;

no rows selected

I have my statistics (columns and extended stats for the column group) but no directives. If I stop here, a new query will probably create a new SQL Plan Directive, which will became PERMANENT and will trigger Adaptive Dynamic Sampling. I want to avoid that and get my disabled directive from the previous environment.

Unpack directive

SQL> select dbms_spd.unpack_stgtab_directive('STGTAB',user,9456295843023884415) from dual;

DBMS_SPD.UNPACK_STGTAB_DIRECTIVE('STGTAB',USER,9456295843023884415)
-------------------------------------------------------------------
                                                                  0

Look at the returned number: no directive has been unpacked. Because I’m now into another schema, I have to update the owner. I don’t know if there is a better way to do it, but here I update the STGTAB:

SQL> update stgtab set c1='DEMO_SITE2';

6 rows updated.

SQL> commit;

Commit complete.

don’t forget to commit. It doesn’t work if you don’t.

SQL> select dbms_spd.unpack_stgtab_directive('STGTAB',user,9456295843023884415) from dual;

DBMS_SPD.UNPACK_STGTAB_DIRECTIVE('STGTAB',USER,9456295843023884415)
-------------------------------------------------------------------
                                                                  1

SQL> select directive_id,state,created,last_modified,last_used,enabled,extract(notes,'//internal_state/text()') internal_state from dba_sql_plan_directives where directive_id in( select directive_id from dba_sql_plan_dir_objects where owner=user ) order by created;

           DIRECTIVE_ID STATE      CREATED  LAST_MOD LAST_USE ENABLED INTERNAL_
----------------------- ---------- -------- -------- -------- ------- ---------
   18397758907897483632 USABLE     18:09:12                   NO      PERMANENT

The directive is there. It’s disabled which is what I wanted. Creation date and last used has been reset. If you see a directive with a status different than NEW and without a LAST_USED then it’s an imported one. Note that the directive ID has changed.

Conclusion

When you have directives in HAS_STATS, then because Data Pump imports the statistics by default (including extended statistics), you probably don’t need to import the SQL Plan Directives. But if you disabled some statistics and want the same in another environment, you have to pack/import/unpack them.

This morning event was a great event. Thanks Ludovico for the picture.