Oracle DBMS_SQLTUNE_UTIL2
Version 26ai

General Information
Library Note Morgan's Library Page Header
The best Oracle News for FY2026

Oracle Database 26ai will be available on generic Linux platforms in January and soon on AIX and Windows
Purpose This package is for shared utility functions that need to be part of an INVOKER rights package. Like the other dbms_sqltune_util# packages, it should NOT be documented. If a function only needs to be accessible from the dbms_sqltune/sqldiag/etc feature layer, do not put it here, but rather in the infrastructure layer (prvssqlf). This layer is for code that should be globally accessible, even from the internal package.
AUTHID CURRENT_USER
Constants
Name Data Type Value
General
DB_TYPE_ROOT VARCHAR2(4) 'ROOT'
DB_TYPE_PDB VARCHAR2(3) 'PDB'
DB_TYPE_IMP VARCHAR2(8) 'IMPORTED'
STR_NO VARCHAR2(3) 'no'
STR_YES VARCHAR2(3) 'yes'
Dependencies
ANYDATA DBMS_SPM PRVTEMX_ADMIN
AWR_PDB_DATABASE_INSTANCE DBMS_SPM_INTERNAL PRVTEMX_CELL
AWR_PDB_PDB_INSTANCE DBMS_SQLDIAG PRVTEMX_PERF
CDB_USERS DBMS_SQLDIAG_INTERNAL PRVT_ADVISOR
DATABASE_PROPERTIES DBMS_SQLPA PRVT_ASH_OMX
DBMS_ADVISOR DBMS_SQLTUNE PRVT_AWRV_METADATA
DBMS_ASH_INTERNAL DBMS_SQLTUNE_INTERNAL PRVT_AWR_VIEWER
DBMS_ASSERT DBMS_SQLTUNE_LIB PRVT_SQLADV_INFRA
DBMS_AUTO_REPORT DBMS_SQLTUNE_UTIL1 SQLPROF_ATTR
DBMS_AUTO_REPORT_INTERNAL DBMS_STANDARD SQL_BIND
DBMS_PERF DBMS_SYS_ERROR SQL_BINDS
DBMS_REPORT DBMS_UTILITY SQL_BIND_SET
DBMS_SMB DBMS_XPLAN SYSTEM_PRIVILEGE_MAP
DBMS_SMB_INTERNAL PLITBLM WRI$_REPT_AWRV
Documented No
Exceptions
Error Code Reason
ORA-13768 Snapshot ID must be between <beginning snap_id> and <max_possible_valid_snap_id>;
First Available 10.1
Security Model Owned by SYS with EXECUTE granted to PUBLIC
Source {ORACLE_HOME}/rdbms/admin/dbmssqlu.sql
Subprograms
 
CHECK_PRIV
Does a callout into the kernel to check for the given system privilege. It returns TRUE or FALSE if the current user has the privilege enabled. dbms_sqltune_util2.check_priv(priv IN VARCHAR2) RETURN BOOLEAN;
conn / as sysdba
BEGIN
  IF dbms_sqltune_util2.check_priv('SYSDBA') THEN
    dbms_output.put_line('T');
  ELSE
    dbms_output.put_line('F');
  END IF;
END;
/
T

PL/SQL procedure successfully completed.
 
CHOOSEAWRFORPDB
Determines the location/prefix of the AWR view to use for the database dbms_sqltune_util2.chooseAWRforPDB(beginTime IN DATE) RETURN VARCHAR2;
SELECT dbms_sqltune_util2.chooseAWRforPDB(SYSDATE);

DBMS_SQLTUNE_UTIL2.CHOOSEAWRFORPDB(SYSDATE)
-------------------------------------------
AWR_PDB


SELECT DECODE(owner#, 0, 'PUBLIC', 1, 'SYS', 'OTHER') AS OWNER,
       name AS OBJECT_NAME,
       DECODE(type#, 4, 'SYNONYM', 5, 'VIEW', 'OTHER') AS TYPE
FROM obj$
SAMPLE(5)
WHERE name LIKE 'AWR_PDB%'
ORDER BY 1,3,2;

OWNER   OBJECT_NAME                   TYPE
------- ----------------------------- -------
PUBLIC  AWR_PDB_BASELINE_TEMPLATE     SYNONYM
PUBLIC  AWR_PDB_DISPATCHER            SYNONYM
PUBLIC  AWR_PDB_FILESTATXS            SYNONYM
PUBLIC  AWR_PDB_LOG                   SYNONYM
PUBLIC  AWR_PDB_MTTR_TARGET_ADVICE    SYNONYM
PUBLIC  AWR_PDB_PGA_STAT              SYNONYM
PUBLIC  AWR_PDB_PLAN_OPTION_NAME      SYNONYM
PUBLIC  AWR_PDB_RSRC_PDB_METRIC       SYNONYM
PUBLIC  AWR_PDB_SERVICESTAT           SYNONYM
PUBLIC  AWR_PDB_SNAPSHOT              SYNONYM
PUBLIC  AWR_PDB_TOPLEVELCALL_NAME     SYNONYM
PUBLIC  AWR_PDB_WAITCLASSMET_HISTORY  SYNONYM
SYS     AWR_PDB_ASM_BAD_DISK          VIEW
SYS     AWR_PDB_CONN_SYSMETRIC_SUMM   VIEW
SYS     AWR_PDB_FILEMETRIC_HISTORY    VIEW
SYS     AWR_PDB_PERSISTENT_SUBS       VIEW
SYS     AWR_PDB_REPLICATION_TXN_STATS VIEW
SYS     AWR_PDB_SESSMETRIC_HISTORY    VIEW
SYS     AWR_PDB_SYSSTAT               VIEW
SYS     AWR_PDB_TBSPC_SPACE_USAGE     VIEW
SYS     AWR_PDB_WR_CONTROL            VIEW
 
GET_CLOUD_SERVICE_TYPE
Returns _cloud_service_type parameter for cloud service type

Interestingly, NONE was returned from 21.1 running in the OCI cloud
dbms_sqltune_util2.get_cloud_service_type RETURN VARCHAR2;

Valid return values
CLOUD_SERVICE_TYPE_NONE  => 'NONE';
CLOUD_SERVICE_TYPE_ADW_D => 'ADW-D';
CLOUD_SERVICE_TYPE_ADW_S => 'ADW-S';
CLOUD_SERVICE_TYPE_ATP_D => 'ATP-D';
CLOUD_SERVICE_TYPE_ATP_S => 'ATP-S';
CLOUD_SERVICE_TYPE_OTHER => 'OTHER';
SELECT dbms_sqltune_util2.get_cloud_service_type;

GET_CLOUD_SERVICE_TYPE
----------------------
NONE
 
GET_SQLSET_USERBINDS
Used by dbms_sqltune.unpack_sqlsets_bulk: Gets the binds of a given SQL statement from a table and converts them into a varray as required by sqlset_row. dbms_sqltune_util2.get_sqlset_userbinds(
get_sqlset_userbinds(
sql_id          IN VARCHAR2,
plan_hash_value IN NUMBER,
sqlset_name     IN VARCHAR2,
sqlset_owner    IN VARCHAR2,
table_name      IN VARCHAR2)
RETURN sys.sql_binds;
TBD
 
GET_TIMING_INFO
Returns elapsed and CPU timing information for a section of PL/SQL code dbms_sqltune_util2.get_timing_info(
phase   IN     BINARY_INTEGER,
elapsed IN OUT NUMBER,
cpu     IN OUT NUMBER);
TBD
 
GET_TZ_OFFSET
Returns the timezone offset from systimestamp dbms_sqltune_util2.get_tz_offset RETURN VARCHAR2;
SELECT dbms_sqltune_util2.get_tz_offset;

GET_TZ_OFFSET
-------------
0:0
 
IS_IMPORTED_CDB
Checks whether the dbid is imported CDB or not dbms_sqltune_util2.is_imported_cdb(p_dbid IN NUMBER) RETURN VARCHAR22;
SELECT dbid
FROM v$database;

       DBID
-----------
 3091983078


SELECT dbms_sqltune_util2.is_imported_cdb(3091983078);

DBMS_SQLTUNE_UTIL2.IS_IMPORTED_CDB(3091983078)
----------------------------------------------
no
 
IS_IMPORTED_PDB
hecks whether the dbid is imported PDB or not dbms_sqltune_util2.is_imported_pdb(p_dbid IN NUMBER) RETURN VARCHAR22;
SELECT dbid, name
FROM v$containers
ORDER BY 1;

DBID        NAME
----------- ----------
1849875810  PDB$SEED
3091983078  CDB$ROOT
3563226870  PDBDEV


SELECT dbms_sqltune_util2.is_imported_pdb(700560205);

DBMS_SQLTUNE_UTIL2.IS_IMPORTED_CDB(7005602054)
----------------------------------------------
no
 
IS_PDB
Returns TRUE if the current database is a PDB

Returns FALSE in CDB$ROOT
dbms_sqltune_util2.is_pdb RETURN BOOLEAN;
BEGIN
  IF dbms_sqltune_util2.is_pdb THEN
    dbms_output.put_line('T');
  ELSE
    dbms_output.put_line('F');
  END IF;
END;
/
F

PL/SQL procedure successfully completed.
 
IS_RAS_USER
Returns TRUE or FALSE based if the current user is a Real Application Security User (RAS) user. This function is used by create_tuning_task, schedule_tuning_task and create_analysis_task. dbms_sqltune_util2.is_ras_user RETURN BOOLEAN;
BEGIN
  IF dbms_sqltune_util2.is_ras_user THEN
    dbms_output.put_line('Using Real Application Security');
  ELSE
    dbms_output.put_line('Not Using Real Application Security');
  END IF;
END;
/
Not Using Real Application Security

PL/SQL procedure successfully completed.
 
IS_SYSTEM_DATA_LOCKED
Returns YES if a LOCKDOWN PROFILE is enabled, else NO dbms_sqltune_util2.is_system_data_locked RETURN VARCHAR2;
SELECT dbms_sqltune_util2.is_system_data_locked;

IS_SYSTEM_DATA_LOCKED
----------------------
NO
 
RESOLVE_DATABASE_TYPE
Resolves the type of database that corresponds to the dbid given as parameter. It is used by get_awr_view_location function to determine the location of AWR views. dbms_sqltune_util2.resolve_database_type(dbid IN NUMBER) RETURN VARCHAR2;
SELECT dbid
FROM v$database;

      DBID
----------
3091983078


SELECT dbms_sqltune_util2.resolve_database_type(3091983078);

DBMS_SQLTUNE_UTIL2.RESOLVE_DATABASE_TYPE(3091983078)
----------------------------------------------------
ROOT
 
RESOLVE_USERNAME
When passed a NULL name, this function returns the current schema owner. Otherwise, it returns the name passed in, after validating it. dbms_sqltune_util2.resolve_username(
user_name IN VARCHAR2,
validate  IN BOOLEAN := TRUE,
con_id    IN NUMBER  := NULL)
RETURN VARCHAR2;
conn uwclass/uwclass@pdbdev

DECLARE
 retVal VARCHAR2(30);
BEGIN
  retVal := dbms_sqltune_util2.resolve_username(USER);
  dbms_output.put_line(retVal);
END;
/
SYS

PL/SQL procedure successfully completed.
 
SQL_BINDS_NTAB_TO_VARRAY
Converts the sql binds data from the nested table stored in the staging table on an unpack/pack to the varray type used in the SQLSET_ROW dbms_sqltune_util2.sql_binds_ntab_to_varray(binds_ntab IN sys.sql_bind_set)
RETURN sys.sql_binds;
TBD
 
SQL_BINDS_VARRAY_TO_NTAB
Converts the sql binds data from a VARRAY as it exists in SQLSET_ROW into a nested table that can be stored in the staging table dbms_sqltune_util2.sql_binds_varray_to_ntab(binds_varray IN sys.sql_binds)
RETURN sys.sql_bind_set;
TBD
 
USER_ID_TO_NAME (new 23ai)
Undocumented dbms_sqltune_util2.user_id_to_name(
user_identifier IN NUMBER,
container_id    IN NUMBER)
RETURN VARCHAR2;
SELECT dbms_sqltune_util2,user_id_to_name(9, 1);

DBMS_SQLTUNE_UTIL2.UESR_ID_TO_NAME(9,1)
---------------------------------------
SYSTEM
 
VALIDATE_SNAPSHOT (new 23ai parameter)
Checks whether a snapshot id interval is valid. It raises an error if passed an invalid interval. dbms_sqltune_util2.validate_snapshot(
begin_snap IN     NUMBER,
end_snap   IN     NUMBER,
awr_dbid   IN OUT NUMBER,
incl_bid   IN     BOOLEAN := FALSE);
SELECT TO_CHAR(s.startup_time,' DD MON "at" HH24:MI:SS') INSTART_FMT,
di.instance_name INST_NAME, di.db_name DB_NAME, s.snap_id SNAP_ID,
TO_CHAR(s.end_interval_time,'DD MON YYYY HH24:MI') SNAPDAT, s.snap_level LVL
FROM dba_hist_snapshot s, dba_hist_database_instance di
WHERE di.dbid = s.dbid
AND di.instance_number = s.instance_number
AND di.startup_time = s.startup_time
ORDER BY snap_id;

DECLARE
 outVal NUMBER;
BEGIN
  dbms_sqltune_util2.validate_snapshot(1955, 1965, outVal);
  dbms_output.put_line(TO_CHAR(outVal);
END;
/
3091983078

PL/SQL procedure successfully completed.


SELECT max(snap_id)+100
FROM dba_hist_snapshot;

MAX(SNAP_ID)+100
----------------
            2065


exec dbms_sqltune_util2.validate_snapshot(2376, 9999);
     *
ORA-13768: Snapshot ID must be between 1759 and 1965.
 
VARR_TO_HINTS_XML
Converts sqlprof_attr object type to XML format dbms_sqltune_util2.varr_to_hints_xml(varr IN sqlprof_attr) RETURN CLOB;
TBD

Related Topics
Built-in Functions
Built-in Packages
DBMS_AUTO_SQLTUNE
DBMS_SQLDIAG
DBMS_SQLPA
DBMS_SQLSET
DBMS_SQLTUNE
DBMS_SQLTUNE_UTIL0
DBMS_SQLTUNE_UTIL1
PRVTEMX_PERF
What's New In 21c
What's New In 26ai

Morgan's Library Page Footer
This site is maintained by Daniel Morgan. Last Updated: This site is protected by copyright and trademark laws under U.S. and International law. © 1998-2026 Daniel A. Morgan All Rights Reserved