You can use DBMS_SQLTUNE.ALTER_SQL_PROFILE to change the status, name, description, or category of a SQL profile, but you can't alter it from exact to force matching. Instead, you would have to recreate it. That is easy if you have the script that you used to create it in the first place. There is another way.
Oracle support note How to Move SQL Profiles from One Database to Another (Including to Higher Versions) (Doc ID 457531.1) describes a process to export SQL profiles to a staging table that can be imported into another database. This provides an opportunity to alter a profile by updating the data in the staging table. There are two columns in the staging table that have to be updated.
- SQLFLAGS must be updated from 0 (indicating an exact match profile) to 1 (indicating a force match profile)
- SIGNATURE must be recalculated as a force matching signature using DBMS_SQLTUNE.SQLTEXT_TO_SIGNATURE.
Demonstration
I am going to create a small table with a unique index.
CREATE TABLE t (a not null, b) AS
SELECT rownum, ceil(sqrt(rownum)) FROM dual connect by level <= 100;
create unique index t_idx on t(a);
exec dbms_stats.gather_table_stats(user,'T');
ttitle off
select * from dba_sql_profiles where name like 'my%sql_profile%';
explain plan for SELECT * FROM t WHERE a = 42;
ttitle 'Default Execution plan without profiles (index scan)'
select * from table(dbms_xplan.display(null,null,'ADVANCED +ADAPTIVE -PROJECTION'));
Without any SQL profiles, when I query by the unique key I get a unique index scan.
Plan hash value: 2929955852
-------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 6 | 1 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| T | 1 | 6 | 1 (0)| 00:00:01 |
|* 2 | INDEX UNIQUE SCAN | T_IDX | 1 | | 0 (0)| 00:00:01 |
-------------------------------------------------------------------------------------
Now I am going to create two SQL profiles. I have deliberately put the same SQL text into both SQL Profiles.
- my_sql_profile is exact matching
- my_sql_profile_force is force matching.
DECLARE
signature INTEGER;
sql_txt CLOB;
h SYS.SQLPROF_ATTR;
BEGIN
sql_txt := q'[
SELECT * FROM t WHERE a = 54
]';
h := SYS.SQLPROF_ATTR(
q'[BEGIN_OUTLINE_DATA]',
q'[IGNORE_OPTIM_EMBEDDED_HINTS]',
q'[FULL(@"SEL$1" "T"@"SEL$1")]',
q'[END_OUTLINE_DATA]');
signature := DBMS_SQLTUNE.SQLTEXT_TO_SIGNATURE(sql_txt);
DBMS_SQLTUNE.IMPORT_SQL_PROFILE (
sql_text => sql_txt,
profile => h,
name => 'my_sql_profile',
category => 'DEFAULT',
validate => TRUE,
replace => TRUE,
force_match => FALSE
);
END;
/
DECLARE
signature INTEGER;
sql_txt CLOB;
h SYS.SQLPROF_ATTR;
BEGIN
sql_txt := q'[
SELECT * FROM t WHERE a = 54
]';
h := SYS.SQLPROF_ATTR(
q'[BEGIN_OUTLINE_DATA]',
q'[IGNORE_OPTIM_EMBEDDED_HINTS]',
q'[FULL(@"SEL$1" "T"@"SEL$1")]',
q'[END_OUTLINE_DATA]');
signature := DBMS_SQLTUNE.SQLTEXT_TO_SIGNATURE(sql_txt);
DBMS_SQLTUNE.IMPORT_SQL_PROFILE (
sql_text => sql_txt,
profile => h,
name => 'my_sql_profile_force',
category => 'DEFAULT',
validate => TRUE,
replace => TRUE,
force_match => TRUE
);
END;
/
ttitle off
select * from dba_sql_profiles where name like 'my%sql_profile%';
NAME CATEGORY SIGNATURE SQL_TEXT CREATED
------------------------------ ---------- --------------------- -------------------------------------------------------------------------------- ------------------------------
LAST_MODIFIED DESCRIPTION TYPE STATUS FOR TASK_ID TASK_EXEC_NAME TASK_OBJ_ID TASK_FND_ID TASK_REC_ID TASK_CON_DBID
------------------------------ -------------------- ------- -------- --- ---------- -------------------- ----------- ----------- ----------- -------------
my_sql_profile DEFAULT 9394869341287877934 31-JUL-21 10.47.34.243454
SELECT * FROM t WHERE a = 54
31-JUL-21 10.47.34.000000 MANUAL ENABLED NO
my_sql_profile_force DEFAULT 11431056000319719221 31-JUL-21 10.47.34.502721
SELECT * FROM t WHERE a = 54
31-JUL-21 10.47.34.000000 MANUAL ENABLED YES
The force match profile works if the literal value is different from that in the profiles.
explain plan for SELECT * FROM t WHERE a = 42;
select * from table(dbms_xplan.display(null,null,'ADVANCED +ADAPTIVE -PROJECTION'));
Plan hash value: 1601196873
--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 6 | 3 (0)| 00:00:01 |
|* 1 | TABLE ACCESS FULL| T | 1 | 6 | 3 (0)| 00:00:01 |
--------------------------------------------------------------------------
…
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("A"=42)
Hint Report (identified by operation id / Query Block Name / Object Alias):
Total hints for statement: 2
---------------------------------------------------------------------------
0 - STATEMENT
- IGNORE_OPTIM_EMBEDDED_HINTS
1 - SEL$1 / T@SEL$1
- FULL(@"SEL$1" "T"@"SEL$1")
Note
-----
- SQL profile "my_sql_profile_force" used for this statement
The exact match profile takes precedence of the force match profile.
explain plan for SELECT * FROM t WHERE a = 54;
select * from table(dbms_xplan.display(null,null,'ADVANCED +ADAPTIVE -PROJECTION'));
Plan hash value: 1601196873
--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 6 | 3 (0)| 00:00:01 |
|* 1 | TABLE ACCESS FULL| T | 1 | 6 | 3 (0)| 00:00:01 |
--------------------------------------------------------------------------
…
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("A"=54)
Hint Report (identified by operation id / Query Block Name / Object Alias):
Total hints for statement: 2
---------------------------------------------------------------------------
0 - STATEMENT
- IGNORE_OPTIM_EMBEDDED_HINTS
1 - SEL$1 / T@SEL$1
- FULL(@"SEL$1" "T"@"SEL$1")
Note
-----
- SQL profile "my_sql_profile" used for this statement
I am now going to follow the process to export the SQL Profiles to a staging table, and subsequently reimport them.
exec DBMS_SQLTUNE.CREATE_STGTAB_SQLPROF(table_name=>'STAGE',schema_name=>user);
exec DBMS_SQLTUNE.PACK_STGTAB_SQLPROF (staging_table_name =>'STAGE',profile_name=>'my_sql_profile');
exec DBMS_SQLTUNE.PACK_STGTAB_SQLPROF (staging_table_name =>'STAGE',profile_name=>'my_sql_profile_force');
There is a row in the staging table for each profile and you can see the differences between them.
select signature, sql_handle, obj_name, obj_type, sql_text, sqlflags from STAGE;
SIGNATURE SQL_HANDLE OBJ_NAME
--------------------- ------------------------------ ---------------------------------------------------------------------
OBJ_TYPE SQL_TEXT SQLFLAGS
------------------------------ -------------------------------------------------------------------------------- ----------
9394869341287877934 SQL_826147e3c6ac0d2e my_sql_profile
SQL_PROFILE 0
SELECT * FROM t WHERE a = 54
11431056000319719221 SQL_9ea344de32a78735 my_sql_profile_force
SQL_PROFILE 1
SELECT * FROM t WHERE a = 54
I will update the staging table using this PL/SQL loop (because SQL doesn't recognise TRUE as a boolean constant).
DECLARE
l_sig INTEGER;
BEGIN
FOR i IN (
SELECT rowid, stage.* FROM stage WHERE sqlflags = 0 FOR UPDATE
) LOOP
l_sig := dbms_sqltune.sqltext_to_signature(i.sql_text,TRUE);
UPDATE stage
SET signature = l_sig
, sqlflags = 1
WHERE sqlflags = 0
AND rowid = i.rowid;
END LOOP;
END;
/
And now the profiles look the same.
select signature, sql_handle, obj_name, obj_type, sql_text, sqlflags from STAGE;
SIGNATURE SQL_HANDLE OBJ_NAME
--------------------- ------------------------------ ---------------------------------------------------------------------
OBJ_TYPE SQL_TEXT SQLFLAGS
------------------------------ -------------------------------------------------------------------------------- ----------
11431056000319719221 SQL_826147e3c6ac0d2e my_sql_profile
SQL_PROFILE 1
SELECT * FROM t WHERE a = 54
11431056000319719221 SQL_9ea344de32a78735 my_sql_profile_force
SQL_PROFILE 1
SELECT * FROM t WHERE a = 54
But I can't just reimport my_sql_profile from the staging replacing the one in the database because I will get ORA-13841: SQL profile named my_sql_profile already exists for a different signature/category pair. To avoid this error I must either drop the profile or rename it.
I am going to rename the existing exact matching profile, and also disable it and move it to another category to stop it from matching my statement in preference to the force matching profile (see previous post Clashing SQL Profiles - Exact Matching Profiles Take Precedence Over Force Matching Profiles), and thus I can go back to it later if needed.
I will drop my example force matching profile. I no longer need that.
Then, I can reimport the profile from the staging table.
exec dbms_sqltune.alter_sql_profile(name=>'my_sql_profile', attribute_name=>'NAME',value=>'my_old_sql_profile');
exec dbms_sqltune.alter_sql_profile(name=>'my_old_sql_profile', attribute_name=>'CATEGORY',value=>'DO_NOT_USE');
exec dbms_sqltune.alter_sql_profile(name=>'my_old_sql_profile', attribute_name=>'STATUS',value=>'DISABLED');
exec dbms_sqltune.drop_sql_profile('my_sql_profile_force',TRUE);
EXEC DBMS_SQLTUNE.UNPACK_STGTAB_SQLPROF(profile_name => 'my_sql_profile', replace => TRUE, staging_table_name => 'STAGE');
I can see in the SQL profile table that my SQL profile is now force matching, and it has a different signature to the old one that is exact matching.
ttitle off
select * from dba_sql_profiles where name like 'my%sql_profile%';
NAME CATEGORY SIGNATURE SQL_TEXT CREATED
------------------------------ ---------- --------------------- -------------------------------------------------------------------------------- ------------------------------
LAST_MODIFIED DESCRIPTION TYPE STATUS FOR TASK_ID TASK_EXEC_NAME TASK_OBJ_ID TASK_FND_ID TASK_REC_ID TASK_CON_DBID
------------------------------ -------------------- ------- -------- --- ---------- -------------------- ----------- ----------- ----------- -------------
my_old_sql_profile DO_NOT_USE 9394869341287877934 31-JUL-21 10.54.58.694037
SELECT * FROM t WHERE a = 54
31-JUL-21 10.55.00.000000 MANUAL DISABLED NO
my_sql_profile DEFAULT 11431056000319719221 31-JUL-21 10.55.01.005377
SELECT * FROM t WHERE a = 54
31-JUL-21 10.55.01.000000 MANUAL ENABLED YES
Both my queries now match the new force matching version of the profile.
explain plan for SELECT * FROM t WHERE a = 42;
ttitle 'Execution plan with force match profile (full scan)'
select * from table(dbms_xplan.display(null,null,'ADVANCED +ADAPTIVE -PROJECTION'));
Plan hash value: 1601196873
--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 6 | 3 (0)| 00:00:01 |
|* 1 | TABLE ACCESS FULL| T | 1 | 6 | 3 (0)| 00:00:01 |
--------------------------------------------------------------------------
…
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("A"=42)
Hint Report (identified by operation id / Query Block Name / Object Alias):
Total hints for statement: 2
---------------------------------------------------------------------------
0 - STATEMENT
- IGNORE_OPTIM_EMBEDDED_HINTS
1 - SEL$1 / T@SEL$1
- FULL(@"SEL$1" "T"@"SEL$1")
Note
-----
- SQL profile "my_sql_profile" used for this statement
explain plan for SELECT * FROM t WHERE a = 54;
select * from table(dbms_xplan.display(null,null,'ADVANCED +ADAPTIVE -PROJECTION'));
Plan hash value: 1601196873
--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 6 | 3 (0)| 00:00:01 |
|* 1 | TABLE ACCESS FULL| T | 1 | 6 | 3 (0)| 00:00:01 |
--------------------------------------------------------------------------
…
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("A"=54)
Hint Report (identified by operation id / Query Block Name / Object Alias):
Total hints for statement: 2
---------------------------------------------------------------------------
0 - STATEMENT
- IGNORE_OPTIM_EMBEDDED_HINTS
1 - SEL$1 / T@SEL$1
- FULL(@"SEL$1" "T"@"SEL$1")
Note
-----
- SQL profile "my_sql_profile" used for this statement
The script used for this demonstration is available on GitHub