SQL Profiles are a powerful tool to improve performance of SQL queries in your Oracle Database.
A SQL profile is a database object that contains auxiliary statistics specific to a SQL statement.
Conceptually, a SQL profile is to a SQL statement what object-level statistics are to a table or index. SQL profiles are created when a DBA invokes SQL Tuning Advisor.
SQL profile is a collection of auxiliary statistics on a query, including all tables and columns referenced in the query. The profile is stored in the data dictionary. The optimizer uses this information during optimization to determine the most optimal plan.

NOTE: TAKE SNIP OF PREVIOUS AND CURRENT PLAN HASH VALUE WITH SQLID.
STEP-1: CHECK FOR PERMORMENCE AND PHV RELATED STUFF
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 | set lines 155 col execs for 999,999,999 col avg_etime for 999,999.999 col avg_lio for 999,999,999.9 col begin_interval_time for a30 col node for 99999 break on plan_hash_value on startup_time skip 1 select ss.snap_id, ss.instance_number node, begin_interval_time, sql_id, plan_hash_value, nvl(executions_delta,0) execs, (elapsed_time_delta/decode(nvl(executions_delta,0),0,1,executions_delta))/1000000 avg_etime, (buffer_gets_delta/decode(nvl(buffer_gets_delta,0),0,1,executions_delta)) avg_lio from DBA_HIST_SQLSTAT S, DBA_HIST_SNAPSHOT SS where sql_id = nvl('&sql_id','4dqs2k5tynk61') and ss.snap_id = S.snap_id and ss.instance_number = S.instance_number and executions_delta > 0 order by 1, 2, 3 / SNAP_ID NODE BEGIN_INTERVAL_TIME SQL_ID PLAN_HASH_VALUE EXECS AVG_ETIME AVG_LIO ---------- ------ ------------------------------ ------------- --------------- ------------ ------------ -------------- 91470 1 03-JAN-21 11.00.51.458 PM byjakj1g6u7ra 930483739 1 1,651.233 4,140,051.0 91475 1 04-JAN-21 01.30.27.705 AM byjakj1g6u7ra 3363986154 2 171.964 650,312.0 91477 1 04-JAN-21 02.30.39.841 AM byjakj1g6u7ra 1 312.828 442,130.0 |
STEP-2: CREATE PROFILE BY USING SCRIPT WITH SAME NAME.
Below are the contents that need to be feed in coe_xfr_sql_profile.sql file.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 | SPO coe_xfr_sql_profile.log; SET DEF ON TERM OFF ECHO ON FEED OFF VER OFF HEA ON LIN 2000 PAGES 100 LONG 8000000 LONGC 800000 TRIMS ON TI OFF TIMI OFF SERVEROUT ON SIZE 1000000 NUMF "" SQLP SQL>; SET SERVEROUT ON SIZE UNL; REM REM $Header: 215187.1 coe_xfr_sql_profile.sql 11.4.5.5 2013/03/01 carlos.sierra $ REM REM Copyright (c) 2000-2013, Oracle Corporation. All rights reserved. REM REM AUTHOR REM carlos.sierra@oracle.com REM REM SCRIPT REM coe_xfr_sql_profile.sql REM REM DESCRIPTION REM This script generates another that contains the commands to REM create a manual custom SQL Profile out of a known plan from REM memory or AWR. The manual custom profile can be implemented REM into the same SOURCE system where the plan was retrieved, REM or into another similar TARGET system that has same schema REM objects referenced by the SQL that generated the known plan. REM REM PRE-REQUISITES REM 1. Oracle Tuning Pack license. REM REM PARAMETERS REM 1. SQL_ID (required) REM 2. Plan Hash Value for which a manual custom SQL Profile is REM needed (required). A list of known plans is presented. REM You may choose from list provided or enter a valid phv REM from a version of the SQL modified with Hints. REM REM EXECUTION REM 1. Connect into SQL*Plus as user with access to data dictionary. REM Do not use SYS. REM 2. Execute script coe_xfr_sql_profile.sql passing SQL_ID and REM plan hash value (parameters can be passed inline or until REM requested). REM REM EXAMPLE REM # sqlplus system REM SQL> START coe_xfr_sql_profile.sql [SQL_ID] [PLAN_HASH_VALUE]; REM SQL> START coe_xfr_sql_profile.sql gnjy0mn4y9pbm 2055843663; REM SQL> START coe_xfr_sql_profile.sql gnjy0mn4y9pbm; REM SQL> START coe_xfr_sql_profile.sql; REM REM NOTES REM 1. For possible errors see coe_xfr_sql_profile.log REM 2. If SQLT is installed in SOURCE, you can use instead: REM sqlt/utl/sqltprofile.sql REM 3. Be aware that using DBMS_SQLTUNE requires a license for REM Oracle Tuning Pack. REM 4. Use a DBA user but not SYS. REM 5. If you get "ORA-06532: Subscript outside of limit, ORA-06512: at line 1" REM Then you may consider this change (only in a test and disposable system): REM create or replace TYPE sys.sqlprof_attr AS VARRAY(5000) of VARCHAR2(500); REM SET TERM ON ECHO OFF; PRO PRO Parameter 1: PRO SQL_ID (required) PRO DEF sql_id = '&1'; PRO WITH p AS ( SELECT plan_hash_value FROM gv$sql_plan WHERE sql_id = TRIM('&&sql_id.') AND other_xml IS NOT NULL UNION SELECT plan_hash_value FROM dba_hist_sql_plan WHERE sql_id = TRIM('&&sql_id.') AND other_xml IS NOT NULL ), m AS ( SELECT plan_hash_value, SUM(elapsed_time)/SUM(executions) avg_et_secs FROM gv$sql WHERE sql_id = TRIM('&&sql_id.') AND executions > 0 GROUP BY plan_hash_value ), a AS ( SELECT plan_hash_value, SUM(elapsed_time_total)/SUM(executions_total) avg_et_secs FROM dba_hist_sqlstat WHERE sql_id = TRIM('&&sql_id.') AND executions_total > 0 GROUP BY plan_hash_value ) SELECT p.plan_hash_value, ROUND(NVL(m.avg_et_secs, a.avg_et_secs)/1e6, 3) avg_et_secs FROM p, m, a WHERE p.plan_hash_value = m.plan_hash_value(+) AND p.plan_hash_value = a.plan_hash_value(+) ORDER BY avg_et_secs NULLS LAST; PRO PRO Parameter 2: PRO PLAN_HASH_VALUE (required) PRO DEF plan_hash_value = '&2'; PRO PRO Values passed to coe_xfr_sql_profile: PRO ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ PRO SQL_ID : "&&sql_id." PRO PLAN_HASH_VALUE: "&&plan_hash_value." PRO SET TERM OFF ECHO ON; WHENEVER SQLERROR EXIT SQL.SQLCODE; -- trim parameters COL sql_id NEW_V sql_id FOR A30; COL plan_hash_value NEW_V plan_hash_value FOR A30; SELECT TRIM('&&sql_id.') sql_id, TRIM('&&plan_hash_value.') plan_hash_value FROM DUAL; VAR sql_text CLOB; VAR sql_text2 CLOB; VAR other_xml CLOB; EXEC :sql_text := NULL; EXEC :sql_text2 := NULL; EXEC :other_xml := NULL; -- get sql_text from memory DECLARE l_sql_text VARCHAR2(32767); BEGIN -- 10g see bug 5017909 FOR i IN (SELECT DISTINCT piece, sql_text FROM gv$sqltext_with_newlines WHERE sql_id = TRIM('&&sql_id.') ORDER BY 1, 2) LOOP IF :sql_text IS NULL THEN DBMS_LOB.CREATETEMPORARY(:sql_text, TRUE); DBMS_LOB.OPEN(:sql_text, DBMS_LOB.LOB_READWRITE); END IF; -- removes NUL characters l_sql_text := REPLACE(i.sql_text, CHR(00), ' '); -- adds a NUL character at the end of each line DBMS_LOB.WRITEAPPEND(:sql_text, LENGTH(l_sql_text) + 1, l_sql_text||CHR(00)); END LOOP; -- if found in memory then sql_text is not null IF :sql_text IS NOT NULL THEN DBMS_LOB.CLOSE(:sql_text); END IF; EXCEPTION WHEN OTHERS THEN DBMS_OUTPUT.PUT_LINE('getting sql_text from memory: '||SQLERRM); :sql_text := NULL; END; / SELECT :sql_text FROM DUAL; -- get sql_text from awr DECLARE l_sql_text VARCHAR2(32767); l_clob_size NUMBER; l_offset NUMBER; BEGIN IF :sql_text IS NULL OR NVL(DBMS_LOB.GETLENGTH(:sql_text), 0) = 0 THEN SELECT sql_text INTO :sql_text2 FROM dba_hist_sqltext WHERE sql_id = TRIM('&&sql_id.') AND sql_text IS NOT NULL AND ROWNUM = 1; END IF; -- if found in awr then sql_text2 is not null IF :sql_text2 IS NOT NULL THEN l_clob_size := NVL(DBMS_LOB.GETLENGTH(:sql_text2), 0); l_offset := 1; DBMS_LOB.CREATETEMPORARY(:sql_text, TRUE); DBMS_LOB.OPEN(:sql_text, DBMS_LOB.LOB_READWRITE); -- store in clob as 64 character pieces plus a NUL character at the end of each piece WHILE l_offset < l_clob_size LOOP IF l_clob_size - l_offset > 64 THEN l_sql_text := REPLACE(DBMS_LOB.SUBSTR(:sql_text2, 64, l_offset), CHR(00), ' '); ELSE -- last piece l_sql_text := REPLACE(DBMS_LOB.SUBSTR(:sql_text2, l_clob_size - l_offset + 1, l_offset), CHR(00), ' '); END IF; DBMS_LOB.WRITEAPPEND(:sql_text, LENGTH(l_sql_text) + 1, l_sql_text||CHR(00)); l_offset := l_offset + 64; END LOOP; DBMS_LOB.CLOSE(:sql_text); END IF; EXCEPTION WHEN OTHERS THEN DBMS_OUTPUT.PUT_LINE('getting sql_text from awr: '||SQLERRM); :sql_text := NULL; END; / SELECT :sql_text2 FROM DUAL; SELECT :sql_text FROM DUAL; -- validate sql_text SET TERM ON; BEGIN IF :sql_text IS NULL THEN RAISE_APPLICATION_ERROR(-20100, 'SQL_TEXT for SQL_ID &&sql_id. was not found in memory (gv$sqltext_with_newlines) or AWR (dba_hist_sqltext).'); END IF; END; / SET TERM OFF; -- get other_xml from memory BEGIN FOR i IN (SELECT other_xml FROM gv$sql_plan WHERE sql_id = TRIM('&&sql_id.') AND plan_hash_value = TO_NUMBER(TRIM('&&plan_hash_value.')) AND other_xml IS NOT NULL ORDER BY child_number, id) LOOP :other_xml := i.other_xml; EXIT; -- 1st END LOOP; EXCEPTION WHEN OTHERS THEN DBMS_OUTPUT.PUT_LINE('getting other_xml from memory: '||SQLERRM); :other_xml := NULL; END; / -- get other_xml from awr BEGIN IF :other_xml IS NULL OR NVL(DBMS_LOB.GETLENGTH(:other_xml), 0) = 0 THEN FOR i IN (SELECT other_xml FROM dba_hist_sql_plan WHERE sql_id = TRIM('&&sql_id.') AND plan_hash_value = TO_NUMBER(TRIM('&&plan_hash_value.')) AND other_xml IS NOT NULL ORDER BY id) LOOP :other_xml := i.other_xml; EXIT; -- 1st END LOOP; END IF; EXCEPTION WHEN OTHERS THEN DBMS_OUTPUT.PUT_LINE('getting other_xml from awr: '||SQLERRM); :other_xml := NULL; END; / -- get other_xml from memory from modified SQL BEGIN IF :other_xml IS NULL OR NVL(DBMS_LOB.GETLENGTH(:other_xml), 0) = 0 THEN FOR i IN (SELECT other_xml FROM gv$sql_plan WHERE plan_hash_value = TO_NUMBER(TRIM('&&plan_hash_value.')) AND other_xml IS NOT NULL ORDER BY child_number, id) LOOP :other_xml := i.other_xml; EXIT; -- 1st END LOOP; END IF; EXCEPTION WHEN OTHERS THEN DBMS_OUTPUT.PUT_LINE('getting other_xml from memory: '||SQLERRM); :other_xml := NULL; END; / -- get other_xml from awr from modified SQL BEGIN IF :other_xml IS NULL OR NVL(DBMS_LOB.GETLENGTH(:other_xml), 0) = 0 THEN FOR i IN (SELECT other_xml FROM dba_hist_sql_plan WHERE plan_hash_value = TO_NUMBER(TRIM('&&plan_hash_value.')) AND other_xml IS NOT NULL ORDER BY id) LOOP :other_xml := i.other_xml; EXIT; -- 1st END LOOP; END IF; EXCEPTION WHEN OTHERS THEN DBMS_OUTPUT.PUT_LINE('getting other_xml from awr: '||SQLERRM); :other_xml := NULL; END; / SELECT :other_xml FROM DUAL; -- validate other_xml SET TERM ON; BEGIN IF :other_xml IS NULL THEN RAISE_APPLICATION_ERROR(-20101, 'PLAN for SQL_ID &&sql_id. and PHV &&plan_hash_value. was not found in memory (gv$sql_plan) or AWR (dba_hist_sql_plan).'); END IF; END; / SET TERM OFF; -- generates script that creates sql profile in target system: SET ECHO OFF; PRO coe_xfr_sql_profile_&&sql_id._&&plan_hash_value..sql. SET FEED OFF LIN 666 TRIMS ON TI OFF TIMI OFF SERVEROUT ON SIZE 1000000 FOR WOR; SET SERVEROUT ON SIZE UNL FOR WOR; SPO OFF; SPO coe_xfr_sql_profile_&&sql_id._&&plan_hash_value..sql; DECLARE l_pos NUMBER; l_clob_size NUMBER; l_offset NUMBER; l_sql_text VARCHAR2(32767); l_len NUMBER; l_hint VARCHAR2(32767); BEGIN DBMS_OUTPUT.PUT_LINE('SPO coe_xfr_sql_profile_&&sql_id._&&plan_hash_value..log;'); DBMS_OUTPUT.PUT_LINE('SET ECHO ON TERM ON LIN 2000 TRIMS ON NUMF 99999999999999999999;'); DBMS_OUTPUT.PUT_LINE('REM'); DBMS_OUTPUT.PUT_LINE('REM $Header: 215187.1 coe_xfr_sql_profile_&&sql_id._&&plan_hash_value..sql 11.4.4.4 '||TO_CHAR(SYSDATE, 'YYYY/MM/DD')||' carlos.sierra $'); DBMS_OUTPUT.PUT_LINE('REM'); DBMS_OUTPUT.PUT_LINE('REM Copyright (c) 2000-2012, Oracle Corporation. All rights reserved.'); DBMS_OUTPUT.PUT_LINE('REM'); DBMS_OUTPUT.PUT_LINE('REM AUTHOR'); DBMS_OUTPUT.PUT_LINE('REM carlos.sierra@oracle.com'); DBMS_OUTPUT.PUT_LINE('REM'); DBMS_OUTPUT.PUT_LINE('REM SCRIPT'); DBMS_OUTPUT.PUT_LINE('REM coe_xfr_sql_profile_&&sql_id._&&plan_hash_value..sql'); DBMS_OUTPUT.PUT_LINE('REM'); DBMS_OUTPUT.PUT_LINE('REM DESCRIPTION'); DBMS_OUTPUT.PUT_LINE('REM This script is generated by coe_xfr_sql_profile.sql'); DBMS_OUTPUT.PUT_LINE('REM It contains the SQL*Plus commands to create a custom'); DBMS_OUTPUT.PUT_LINE('REM SQL Profile for SQL_ID &&sql_id. based on plan hash'); DBMS_OUTPUT.PUT_LINE('REM value &&plan_hash_value..'); DBMS_OUTPUT.PUT_LINE('REM The custom SQL Profile to be created by this script'); DBMS_OUTPUT.PUT_LINE('REM will affect plans for SQL commands with signature'); DBMS_OUTPUT.PUT_LINE('REM matching the one for SQL Text below.'); DBMS_OUTPUT.PUT_LINE('REM Review SQL Text and adjust accordingly.'); DBMS_OUTPUT.PUT_LINE('REM'); DBMS_OUTPUT.PUT_LINE('REM PARAMETERS'); DBMS_OUTPUT.PUT_LINE('REM None.'); DBMS_OUTPUT.PUT_LINE('REM'); DBMS_OUTPUT.PUT_LINE('REM EXAMPLE'); DBMS_OUTPUT.PUT_LINE('REM SQL> START coe_xfr_sql_profile_&&sql_id._&&plan_hash_value..sql;'); DBMS_OUTPUT.PUT_LINE('REM'); DBMS_OUTPUT.PUT_LINE('REM NOTES'); DBMS_OUTPUT.PUT_LINE('REM 1. Should be run as SYSTEM or SYSDBA.'); DBMS_OUTPUT.PUT_LINE('REM 2. User must have CREATE ANY SQL PROFILE privilege.'); DBMS_OUTPUT.PUT_LINE('REM 3. SOURCE and TARGET systems can be the same or similar.'); DBMS_OUTPUT.PUT_LINE('REM 4. To drop this custom SQL Profile after it has been created:'); DBMS_OUTPUT.PUT_LINE('REM EXEC DBMS_SQLTUNE.DROP_SQL_PROFILE(''coe_&&sql_id._&&plan_hash_value.'');'); DBMS_OUTPUT.PUT_LINE('REM 5. Be aware that using DBMS_SQLTUNE requires a license'); DBMS_OUTPUT.PUT_LINE('REM for the Oracle Tuning Pack.'); DBMS_OUTPUT.PUT_LINE('REM 6. If you modified a SQL putting Hints in order to produce a desired'); DBMS_OUTPUT.PUT_LINE('REM Plan, you can remove the artifical Hints from SQL Text pieces below.'); DBMS_OUTPUT.PUT_LINE('REM By doing so you can create a custom SQL Profile for the original'); DBMS_OUTPUT.PUT_LINE('REM SQL but with the Plan captured from the modified SQL (with Hints).'); DBMS_OUTPUT.PUT_LINE('REM'); DBMS_OUTPUT.PUT_LINE('WHENEVER SQLERROR EXIT SQL.SQLCODE;'); DBMS_OUTPUT.PUT_LINE('REM'); DBMS_OUTPUT.PUT_LINE('VAR signature NUMBER;'); DBMS_OUTPUT.PUT_LINE('VAR signaturef NUMBER;'); DBMS_OUTPUT.PUT_LINE('REM'); DBMS_OUTPUT.PUT_LINE('DECLARE'); DBMS_OUTPUT.PUT_LINE('sql_txt CLOB;'); DBMS_OUTPUT.PUT_LINE('h SYS.SQLPROF_ATTR;'); DBMS_OUTPUT.PUT_LINE('PROCEDURE wa (p_line IN VARCHAR2) IS'); DBMS_OUTPUT.PUT_LINE('BEGIN'); DBMS_OUTPUT.PUT_LINE('DBMS_LOB.WRITEAPPEND(sql_txt, LENGTH(p_line), p_line);'); DBMS_OUTPUT.PUT_LINE('END wa;'); DBMS_OUTPUT.PUT_LINE('BEGIN'); DBMS_OUTPUT.PUT_LINE('DBMS_LOB.CREATETEMPORARY(sql_txt, TRUE);'); DBMS_OUTPUT.PUT_LINE('DBMS_LOB.OPEN(sql_txt, DBMS_LOB.LOB_READWRITE);'); DBMS_OUTPUT.PUT_LINE('-- SQL Text pieces below do not have to be of same length.'); DBMS_OUTPUT.PUT_LINE('-- So if you edit SQL Text (i.e. removing temporary Hints),'); DBMS_OUTPUT.PUT_LINE('-- there is no need to edit or re-align unmodified pieces.'); l_clob_size := NVL(DBMS_LOB.GETLENGTH(:sql_text), 0); l_offset := 1; WHILE l_offset < l_clob_size LOOP l_pos := DBMS_LOB.INSTR(:sql_text, CHR(00), l_offset); IF l_pos > 0 THEN l_len := l_pos - l_offset; ELSE -- last piece l_len := l_clob_size - l_pos + 1; END IF; l_sql_text := DBMS_LOB.SUBSTR(:sql_text, l_len, l_offset); /* cannot do such 3 replacement since a line could end with a comment using "--" l_sql_text := REPLACE(l_sql_text, CHR(10), ' '); -- replace LF with SP l_sql_text := REPLACE(l_sql_text, CHR(13), ' '); -- replace CR with SP l_sql_text := REPLACE(l_sql_text, CHR(09), ' '); -- replace TAB with SP */ l_offset := l_offset + l_len + 1; IF l_len > 0 THEN IF INSTR(l_sql_text, '''[') + INSTR(l_sql_text, ']''') = 0 THEN l_sql_text := '['||l_sql_text||']'; ELSIF INSTR(l_sql_text, '''{') + INSTR(l_sql_text, '}''') = 0 THEN l_sql_text := '{'||l_sql_text||'}'; ELSIF INSTR(l_sql_text, '''<') + INSTR(l_sql_text, '>''') = 0 THEN l_sql_text := '<'||l_sql_text||'>'; ELSIF INSTR(l_sql_text, '''(') + INSTR(l_sql_text, ')''') = 0 THEN l_sql_text := '('||l_sql_text||')'; ELSIF INSTR(l_sql_text, '''"') + INSTR(l_sql_text, '"''') = 0 THEN l_sql_text := '"'||l_sql_text||'"'; ELSIF INSTR(l_sql_text, '''|') + INSTR(l_sql_text, '|''') = 0 THEN l_sql_text := '|'||l_sql_text||'|'; ELSIF INSTR(l_sql_text, '''~') + INSTR(l_sql_text, '~''') = 0 THEN l_sql_text := '~'||l_sql_text||'~'; ELSIF INSTR(l_sql_text, '''^') + INSTR(l_sql_text, '^''') = 0 THEN l_sql_text := '^'||l_sql_text||'^'; ELSIF INSTR(l_sql_text, '''@') + INSTR(l_sql_text, '@''') = 0 THEN l_sql_text := '@'||l_sql_text||'@'; ELSIF INSTR(l_sql_text, '''#') + INSTR(l_sql_text, '#''') = 0 THEN l_sql_text := '#'||l_sql_text||'#'; ELSIF INSTR(l_sql_text, '''%') + INSTR(l_sql_text, '%''') = 0 THEN l_sql_text := '%'||l_sql_text||'%'; ELSIF INSTR(l_sql_text, '''$') + INSTR(l_sql_text, '$''') = 0 THEN l_sql_text := '$'||l_sql_text||'$'; ELSE l_sql_text := CHR(96)||l_sql_text||CHR(96); END IF; DBMS_OUTPUT.PUT_LINE('wa(q'''||l_sql_text||''');'); END IF; END LOOP; DBMS_OUTPUT.PUT_LINE('DBMS_LOB.CLOSE(sql_txt);'); DBMS_OUTPUT.PUT_LINE('h := SYS.SQLPROF_ATTR('); DBMS_OUTPUT.PUT_LINE('q''[BEGIN_OUTLINE_DATA]'','); FOR i IN (SELECT /*+ opt_param('parallel_execution_enabled', 'false') */ SUBSTR(EXTRACTVALUE(VALUE(d), '/hint'), 1, 4000) hint FROM TABLE(XMLSEQUENCE(EXTRACT(XMLTYPE(:other_xml), '/*/outline_data/hint'))) d) LOOP l_hint := i.hint; WHILE NVL(LENGTH(l_hint), 0) > 0 LOOP IF LENGTH(l_hint) <= 500 THEN DBMS_OUTPUT.PUT_LINE('q''['||l_hint||']'','); l_hint := NULL; ELSE l_pos := INSTR(SUBSTR(l_hint, 1, 500), ' ', -1); DBMS_OUTPUT.PUT_LINE('q''['||SUBSTR(l_hint, 1, l_pos)||']'','); l_hint := ' '||SUBSTR(l_hint, l_pos); END IF; END LOOP; END LOOP; DBMS_OUTPUT.PUT_LINE('q''[END_OUTLINE_DATA]'');'); DBMS_OUTPUT.PUT_LINE(':signature := DBMS_SQLTUNE.SQLTEXT_TO_SIGNATURE(sql_txt);'); DBMS_OUTPUT.PUT_LINE(':signaturef := DBMS_SQLTUNE.SQLTEXT_TO_SIGNATURE(sql_txt, TRUE);'); DBMS_OUTPUT.PUT_LINE('DBMS_SQLTUNE.IMPORT_SQL_PROFILE ('); DBMS_OUTPUT.PUT_LINE('sql_text => sql_txt,'); DBMS_OUTPUT.PUT_LINE('profile => h,'); DBMS_OUTPUT.PUT_LINE('name => ''coe_&&sql_id._&&plan_hash_value.'','); DBMS_OUTPUT.PUT_LINE('description => ''coe &&sql_id. &&plan_hash_value. ''||:signature||'' ''||:signaturef||'''','); DBMS_OUTPUT.PUT_LINE('category => ''DEFAULT'','); DBMS_OUTPUT.PUT_LINE('validate => TRUE,'); DBMS_OUTPUT.PUT_LINE('replace => TRUE,'); DBMS_OUTPUT.PUT_LINE('force_match => FALSE /* TRUE:FORCE (match even when different literals in SQL). FALSE:EXACT (similar to CURSOR_SHARING) */ );'); DBMS_OUTPUT.PUT_LINE('DBMS_LOB.FREETEMPORARY(sql_txt);'); DBMS_OUTPUT.PUT_LINE('END;'); DBMS_OUTPUT.PUT_LINE('/'); DBMS_OUTPUT.PUT_LINE('WHENEVER SQLERROR CONTINUE'); DBMS_OUTPUT.PUT_LINE('SET ECHO OFF;'); DBMS_OUTPUT.PUT_LINE('PRINT signature'); DBMS_OUTPUT.PUT_LINE('PRINT signaturef'); DBMS_OUTPUT.PUT_LINE('PRO'); DBMS_OUTPUT.PUT_LINE('PRO ... manual custom SQL Profile has been created'); DBMS_OUTPUT.PUT_LINE('PRO'); DBMS_OUTPUT.PUT_LINE('SET TERM ON ECHO OFF LIN 80 TRIMS OFF NUMF "";'); DBMS_OUTPUT.PUT_LINE('SPO OFF;'); DBMS_OUTPUT.PUT_LINE('PRO'); DBMS_OUTPUT.PUT_LINE('PRO COE_XFR_SQL_PROFILE_&&sql_id._&&plan_hash_value. completed'); END; / SPO OFF; SET DEF ON TERM ON ECHO OFF FEED 6 VER ON HEA ON LIN 80 PAGES 14 LONG 80 LONGC 80 TRIMS OFF TI OFF TIMI OFF SERVEROUT OFF NUMF "" SQLP SQL>; SET SERVEROUT OFF; PRO PRO Execute coe_xfr_sql_profile_&&sql_id._&&plan_hash_value..sql PRO on TARGET system in order to create a custom SQL Profile PRO with plan &&plan_hash_value linked to adjusted sql_text. PRO UNDEFINE 1 2 sql_id plan_hash_value CL COL PRO PRO COE_XFR_SQL_PROFILE completed. |
1 2 3 4 5 6 7 8 9 10 11 12 | bash-3.2$ vi coe_xfr_sql_profile.sql bash-3.2$ sqlplus / as sysdba SQL*Plus: Release 11.2.0.4.0 Production on Tue Jan 5 12:49:16 2021 Copyright (c) 1982, 2013, Oracle. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production With the Partitioning, Automatic Storage Management, OLAP, Data Mining and Real Application Testing options |
STEP-3: RUN coe_xfr_sql_profile.sql SCRIPT
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 | SQL> @coe_xfr_sql_profile.sql Parameter 1: SQL_ID (required) Enter value for 1: byjakj1g6u7ra PLAN_HASH_VALUE AVG_ET_SECS --------------- ----------- 3363986154 232.345 930483739 3489.38 Parameter 2: PLAN_HASH_VALUE (required) Enter value for 2: 3363986154 Values passed to coe_xfr_sql_profile: ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ SQL_ID : "byjakj1g6u7ra" PLAN_HASH_VALUE: "3363986154" SQL>BEGIN 2 IF :sql_text IS NULL THEN 3 RAISE_APPLICATION_ERROR(-20100, 'SQL_TEXT for SQL_ID &&sql_id. was not found in memory (gv$sqltext_with_newlines) or AWR (dba_hist_sqltext).'); 4 END IF; 5 END; 6 / SQL>SET TERM OFF; SQL>BEGIN 2 IF :other_xml IS NULL THEN 3 RAISE_APPLICATION_ERROR(-20101, 'PLAN for SQL_ID &&sql_id. and PHV &&plan_hash_value. was not found in memory (gv$sql_plan) or AWR (dba_hist_sql_plan).'); 4 END IF; 5 END; 6 / SQL>SET TERM OFF; - - - - - - Execute coe_xfr_sql_profile_byjakj1g6u7ra_3363986154.sql on TARGET system in order to create a custom SQL Profile with plan 3363986154 linked to adjusted sql_text. COE_XFR_SQL_PROFILE completed. SQL>ho bash-3.2$ bash-3.2$ exit exit |
STEP-4: EXECUTE THE SCRIPT CREATED
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 | SQL>@coe_xfr_sql_profile_byjakj1g6u7ra_3363986154.sql SQL>REM SQL>REM $Header: 215187.1 coe_xfr_sql_profile_byjakj1g6u7ra_3363986154.sql 11.4.4.4 2021/01/05 carlos.sierra $ SQL>REM SQL>REM Copyright (c) 2000-2012, Oracle Corporation. All rights reserved. SQL>REM SQL>REM AUTHOR SQL>REM carlos.sierra@oracle.com SQL>REM PL/SQL procedure successfully completed. SQL>WHENEVER SQLERROR CONTINUE SQL>SET ECHO OFF; SIGNATURE --------------------- 18310185952535799624 SIGNATUREF --------------------- 18310185952535799624 ... manual custom SQL Profile has been created COE_XFR_SQL_PROFILE_byjakj1g6u7ra_3363986154 completed SQL> |
Step 5: Verify if it is using SQL_PROFILE
1 2 3 4 5 | -- Run the problematic SQL and below command parallel select SQL_ID, CHILD_NUMBER, PLAN_HASH_VALUE, SQL_PROFILE FROM V$SQL where sql_id='&SQL_ID'; select * from table(dbms_xplan.display_cursor('dkz7v96ym42c6',null,'ADVANCED ALLSTATS LAST')); |
1 2 3 4 5 6 7 8 | Please verify if it is using new PLAN_HASH_VALUE. Please note if new plan is not using, then flush the HASH VALUE to ensure the new plan is used, then have the apps team restart the process. COLUMN category FORMAT a10 COLUMN sql_text FORMAT a20 SELECT NAME, SQL_TEXT, CATEGORY, STATUS FROM DBA_SQL_PROFILES; |
Dropping a SQL Profile
1 2 3 4 5 6 7 8 9 10 | Connect SQL*Plus to the database with the appropriate privileges, call the DBMS_SQLTUNE.DROP_SQL_PROFILE procedure. The following example drops the profile named my_sql_profile: BEGIN DBMS_SQLTUNE.DROP_SQL_PROFILE ( name => 'my_sql_profile' ); END; / |
Basic tasks of a SQL Profile:

Hope it worked for you !!