Yesterday and today I’ve read or heard two people mention the force_match => TRUE parameter value for DBMS_SQLTUNE.IMPORT_SQL_PROFILE and how it forces a profile to work on all SQL statements that are the same except for their literal values. So, I ran a quick test using the coe_xfr_sql_profile.sql utility that comes with the SQLT scripts that are available for download on Oracle’s support site.
I’ve mentioned in earlier posts how we use coe_xfr_sql_profile.sql to force plans on particular SQL statements using the sql_id of the SQL statement and the plan_hash_value of the plan:
Yesterday I read this post by David Kurtz where he mentions force_match: post
Today I heard Karen Morton mention force_match in her webinar which should soon be posted here: url
So, after the webinar completed I built a test case to see how the force_match=>TRUE option works. I created a test table and ran a query with a literal in the where clause and got its plan showing its sql_id and plan_hash_value:
ORCL:SYSTEM>create table test as select * from dba_tables; ORCL:SYSTEM>SELECT sum(blocks) from test 2 where owner='SYS'; SUM(BLOCKS) ----------- 34633 ORCL:SYSTEM>select * from 2 table(dbms_xplan.display_cursor(null,null,'ALL')); PLAN_TABLE_OUTPUT -------------------------------------------------------------------- SQL_ID 10g08ytt2m5mu, child number 0 ------------------------------------- SELECT sum(blocks) from test where owner='SYS' Plan hash value: 1950795681 --------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| ---------------------------------------------------------------- | 0 | SELECT STATEMENT | | | | 29 (100)| | 1 | SORT AGGREGATE | | 1 | 30 | | |* 2 | TABLE ACCESS FULL| TEST | 992 | 29760 | 29 (0)| ----------------------------------------------------------------
Then I ran coe_xfr_sql_profile.sql to create a profile that forces the plan on the given sql_id:
SQL> @coe_xfr_sql_profile.sql 10g08ytt2m5mu 1950795681
Then, using vi I edited the output of coe_xfr_sql_profile.sql:
vi coe_xfr_sql_profile_10g08ytt2m5mu_1950795681.sql
I searched for force_match and changed the line to read like this:
force_match => TRUE
instead of
force_match => FALSE
There are comments in the script explaining the meaning of these two values but I don’t want to plagiarize the script by including them here. Next I ran the edited script:
sqlplus system/password < coe_xfr_sql_profile_10g08ytt2m5mu_1950795681.sql
Then I ran a test showing that not only the original query with the where clause literal ‘SYS’ would use the profile but the same query with a different literal ‘SYSTEM’ would use the created profile.
ORCL:SYSTEM>SELECT sum(blocks) from test 2 where owner='SYS'; SUM(BLOCKS) ----------- 34633 ORCL:SYSTEM>select * from 2 table(dbms_xplan.display_cursor(null,null,'ALL')); PLAN_TABLE_OUTPUT -------------------------------------------------------------------- SQL_ID 10g08ytt2m5mu, child number 0 ------------------------------------- SELECT sum(blocks) from test where owner='SYS' Plan hash value: 1950795681 ---------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| ---------------------------------------------------------------- | 0 | SELECT STATEMENT | | | | 29 (100)| | 1 | SORT AGGREGATE | | 1 | 30 | | |* 2 | TABLE ACCESS FULL| TEST | 81 | 2430 | 29 (0)| ---------------------------------------------------------------- Note ----- - SQL profile coe_10g08ytt2m5mu_1950795681 used for this statement ORCL:SYSTEM>SELECT sum(blocks) from test 2 where owner='SYSTEM'; SUM(BLOCKS) ----------- 520 ORCL:SYSTEM> ORCL:SYSTEM>select * from 2 table(dbms_xplan.display_cursor(null,null,'ALL')); PLAN_TABLE_OUTPUT -------------------------------------------------------------------- SQL_ID 806ncj0a5fgus, child number 0 ------------------------------------- SELECT sum(blocks) from test where owner='SYSTEM' Plan hash value: 1950795681 ---------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| ---------------------------------------------------------------- | 0 | SELECT STATEMENT | | | | 29 (100)| | 1 | SORT AGGREGATE | | 1 | 30 | | |* 2 | TABLE ACCESS FULL| TEST | 81 | 2430 | 29 (0)| ---------------------------------------------------------------- Note ----- - SQL profile coe_10g08ytt2m5mu_1950795681 used for this statement
Note that a different sql_id = 806ncj0a5fgus represents the second statement but the same plan_hash_value = 1950795681. Also note that the SQL profile has the same name in both plans = coe_10g08ytt2m5mu_1950795681.
Now that I’m aware of the force_match=>TRUE option of DBMS_SQLTUNE.IMPORT_SQL_PROFILE I can use SQL profiles to force plans on queries that have different literal values, but are otherwise identical. This adds a whole new set of problems that can be resolved without modifying the existing code which can really help in a performance firefight.
– Bobby
I am just wondering why not Oracle made this force_match option is true by default in Grid Control SQL Tuning Advisor?
John,
I haven’t used the grid control SQL Tuning Advisor, but the sqlt script coe_xfr_sql_profile.sql has force_match=>FALSE as its default. You can have cases where different literal values need different plans. Imagine if you have some flag where most of the rows have flag=’A’ but only a few have flag=’B’. If you have a query with flag=’A’ in the where clause you would want a full table scan but with flag=’B’ you would want to use an index.
I think force_match=>FALSE makes sense for the default so your profile affects the minimum possible set of queries – only those with exactly the same SQL text.
– Bobby
Pingback: Example of coe_xfr_sql_profile force_match TRUE | Bobby Durrett's DBA Blog
First of all please understand that there is no documentation to use DBMS_SQLTUNE.IMPORT_SQL_PROFILE to create a SQL profile directly
The above procedure is DBMS_SQLTUNE.IMPORT_SQL_PROFILE is internally used by SQL profile mechanism hence there is no documentation available on the procedure.
The same is also used by the coe_xfr_sql_profile.sql script
you can create SQLprofile using coe_xfr_sql_profile.sql which is recommended and suggested way to create sql profile instead of using internal undocumented procedures directly to create SQL profiles.
Thanks for your comment!
Bobby