ACE Director Alum Daniel Morgan, founder of Morgan's Library, is scheduling
complimentary technical Workshops on Database Security for the first 30
Oracle Database customers located anywhere in North America, EMEA, LATAM, or
APAC that send an email to
asra_us@oracle.com. Request a Workshop for
your organization today.
Purpose
Container for a group of unrelated utility procedures and functions
AUTHID
DEFINER
Constants
Name
Data Type
Value
Invalidate Option Flag
INV_ERROR_ON_RESTRICTIONS
PLS_INTEGER
1
SYMLINK Constants
NO_SYMLINK
PLS_INTEGER
0
HAS_SYMLINK
PLS_INTEGER
1
Data Types
-- List of active instance numbers and instance names
-- Starting index of instance_table is 1;
TYPE instance_record IS RECORD (
inst_number NUMBER,
inst_name VARCHAR2(60));
-- array of anydata
TYPE anydata_array IS TABLE OF ANYDATA
INDEX BY BINARY_INTEGER;
-- Lists of database links
TYPE dblink_array IS TABLE OF VARCHAR2(128)
INDEX BY BINARY_INTEGER;
-- Order in which objects should be generated
TYPE index_table_type IS TABLE OF BINARY_INTEGER
INDEX BY BINARY_INTEGER;
-- Instance_table is dense
TYPE instance_table IS TABLE OF instance_record
INDEX BY BINARY_INTEGER;
-- Lists of Long NAME: includes fully qualified attribute names
TYPE lname_array IS TABLE OF VARCHAR2(4000)
INDEX BY BINARY_INTEGER;
-- Lists of large VARCHAR2s should be stored here
TYPE maxname_array IS TABLE OF VARCHAR2(32767)
INDEX BY BINARY_INTEGER;
-- Lists of NAME
TYPE name_array IS TABLE OF dbms_id
INDEX BY BINARY_INTEGER;
-- The order in which objects should be generated is returned here for users
TYPE number_array IS TABLE OF NUMBER
INDEX BY BINARY_INTEGER;
-- Lists of "USER"."NAME"."COLUMN"@LINK
TYPE uncl_array IS TABLE OF VARCHAR2(32767)
INDEX BY BINARY_INTEGER;
-- Lists of NAME that might be quoted should be stored here
TYPE quoted_name_array IS TABLE OF dbms_quoted_id
INDEX BY BINARY_INTEGER;
SUBTYPE maxraw IS RAW(32767);
Dependencies
SELECT name FROM dba_dependencies WHERE referenced_name = 'DBMS_UTILITY'
UNION
SELECT referenced_name FROM dba_dependencies WHERE name = 'DBMS_UTILITY';
-- this query returns 284 objects
Documented
Yes
Exceptions
Error Code
Reason
ORA-00900
Input is not valid
ORA-00942
Current user does not have select privs on all the views and tables recursively referenced in the input SQL
ORA-20000
Insufficient privileges for some object in this schema
ORA-20001
Cannot recompile SYS objects
ORA-24237
inv_not_exist_or_no_priv
ORA-24238
inv_malformed_settings
ORA-24239
inv_restricted_object
ORA-24251
Raised if the input_sql text is not a select statement
ORA-29261
hash size is 0
ORA-29477
Input LOB size exceeds the maximum size of 4GB -1
First Available
7.3.4
Security Model
Owned by SYS with EXECUTE granted to DBSFWUSER, DVSYS, GSMADMIN_INTERNAL, ORDSYS, PUBLIC, and WMSYS.
dbms_utility.active_instances (instance_table OUT INSTANCE_TABLE, instance_count OUT NUMBER);
set serveroutput on
DECLARE
inst_tab dbms_utility.instance_table;
inst_cnt NUMBER;
BEGIN
IF dbms_utility.is_cluster_database THEN
dbms_utility.active_instances(inst_tab, inst_cnt);
dbms_output.put_line('-' || inst_tab.FIRST);
dbms_output.put_line(TO_CHAR(inst_cnt));
ELSE
dbms_output.put_line('Not A Clustered Database');
END IF;
END;
/
Analyzes all the tables, clusters, and indexes in a database
Deprecated in 10g
dbms_utility.analyze_database (
method IN VARCHAR2,
estimate_rows IN NUMBER DEFAULT NULL, -- # of rows to est.
estimate_percent IN NUMBER DEFAULT NULL, -- % of rows for est.
method_opt IN VARCHAR2 DEFAULT NULL);
-- method options:
ESTIMATE, COMPUTE and DELETE
-- method_opt options:
FOR TABLE
FOR ALL [INDEXED] COLUMNS] [SIZE n]
FOR ALL INDEXES
-- requires grant of ANALYZE ANY
exec dbms_utility.analyze_database('ESTIMATE', 100, NULL, 'FOR TABLE');
Analyzes all the tables, clusters, and indexes in a schema
Deprecated in 10g
dbms_utility.analyze_schema (
schema IN VARCHAR2,
method IN VARCHAR2, -- values COMPUTE, DELETE, ESTIMATE
estimate_rows IN NUMBER DEFAULT NULL,
estimate_percent IN NUMBER DEFAULT NULL,
method_opt IN VARCHAR2 DEFAULT NULL);
CREATE OR REPLACE PROCEDURE load_c2t_test AUTHID DEFINER IS
c_string VARCHAR2(250);
cnt BINARY_INTEGER;
my_table dbms_utility.uncl_array;
BEGIN
FOR t_rec IN (SELECT * FROM c2t_test) LOOP
dbms_utility.comma_to_table(t_rec.readline, cnt, my_table);
CREATE OR REPLACE PROCEDURE load_c2t_test AUTHID CURRENT_USER IS
c_string VARCHAR2(250);
cnt BINARY_INTEGER;
my_table dbms_utility.lname_array;
BEGIN
FOR t_rec IN (SELECT * FROM c2t_test) LOOP
dbms_utility.comma_to_table(t_rec.readline, cnt, my_table);
Creates an error table to be used in the EXCEPTION clause of the ALTER TYPE statement
dbms_utility.create_alter_type_error_table(
schema_name IN VARCHAR2,
table_name IN VARCHAR2);
conn uwclass/uwclass@pdbdev
CREATE OR REPLACE TYPE CourseList AS TABLE OF VARCHAR2(30);
/
CREATE TABLE department (
name VARCHAR2(20),
director VARCHAR2(20),
office VARCHAR2(20),
courses CourseList)
NESTED TABLE courses STORE AS courses_tab;
set describe depth all linenum on indent on
desc department
INSERT INTO department
VALUES
('English', 'Lynn Saunders', 'Breakstone Hall 205', CourseList (
'Expository Writing',
'Film and Literature',
'Modern Science Fiction',
'Discursive Writing',
'Modern English Grammar',
'Introduction to Shakespeare',
'Modern Drama',
'The Short Story',
'The American Novel'));
Returns the database's version and compatibility parameter
Oracle documentation does not say that this procedure is deprecated but its use in 19c returns a the following:
PLW-06020: reference to a deprecated entity: DB_VERSION declared
in unit DBMS_UTILITY[532,13]. DBMS_UTILITY.DB_VERSION is
deprecated!
dbms_utility.db_version (version OUT VARCHAR2, compatibility OUT VARCHAR2);
set serveroutput on
DECLARE
ver VARCHAR2(100);
compat VARCHAR2(100);
BEGIN
dbms_utility.db_version(ver, compat);
dbms_output.put_line('Version: ' || ver ||' Compatible: ' || compat);
END;
/
dbms_utility.exec_ddl_statement(parse_string IN VARCHAR2);
-- create a stored procedure owned by a schema with the alter any user system privilege.
CREATE OR REPLACE PROCEDURE sp_alter_user (a_user_name VARCHAR2,
a_user_password VARCHAR2, a_admin VARCHAR2 := 'N') AUTHID DEFINER IS
l_user VARCHAR2(255);
l_user_grants VARCHAR2(255);
l_user_default_role VARCHAR2(255);
BEGIN
l_user := 'alter user ' || a_user_name || ' identified by ' || a_user_password;
-- if they need roles granted
l_user_grants := 'GRANT connect,resource TO ' || a_user_name;
l_user_default_role := 'alter user ' || a_user_name || ' default role dba';
dbms_utility.exec_ddl_statement(l_user);
dbms_utility.exec_ddl_statement(l_user_grants);
dbms_utility.exec_ddl_statement(l_user_default_role);
END sp_alter_user;
/
CREATE OR REPLACE PROCEDURE sp_create_user (a_user_name VARCHAR2,
a_user_password VARCHAR2, a_admin VARCHAR2 := 'N') AUTHID DEFINER IS
l_user VARCHAR2(255);
BEGIN
l_user := 'create user ' || a_user_name ||
' identified by ' || a_user_password ||
' temporary tablespace temp';
dbms_utility.exec_ddl_statement(l_user);
sp_alter_user(a_user_name, a_user_password, a_admin);
END sp_create_user;
/
Recursively replaces any view references in the input SQL query with the corresponding view subquery
dbms_utility.expand_sql_text(
input_sql_text IN CLOB,
output_sql_text OUT NOCOPY CLOB);
conn uwclass/uwclass@pdbdev
CREATE VIEW uwclass.expandv AS
SELECT * FROM servers;
SELECT DISTINCT srvr_id
FROM uwclass.expandv
WHERE srvr_id NOT IN (
SELECT srvr_id
FROM uwclass.expandv
MINUS
SELECT srvr_id
FROM uwclass.serv_inst);
EXPLAIN PLAN FOR
SELECT DISTINCT srvr_id
FROM uwclass.expandv
WHERE srvr_id NOT IN (
SELECT srvr_id
FROM uwclass.expandv
MINUS
SELECT srvr_id
FROM uwclass.serv_inst);
SELECT * FROM TABLE(dbms_xplan.display);
DECLARE
vClobIn CLOB := 'SELECT DISTINCT srvr_id
FROM uwclass.expandv
WHERE srvr_id NOT IN (
SELECT srvr_id
FROM uwclass.expandv
MINUS
SELECT srvr_id
FROM uwclass.serv_inst)';
vClobOut CLOB;
BEGIN
dbms_utility.expand_sql_text(vClobIn, vClobOut);
dbms_output.put_line(vClobOut);
END;
/
CREATE VIEW uwclass.layer1 AS
SELECT * FROM uwclass.servers;
CREATE VIEW uwclass.layer2 AS
SELECT srvr_id, netaddress
FROM uwclass.layer1
WHERE status = 'Y';
CREATE VIEW uwclass.table_join AS
SELECT DISTINCT srvr_id
FROM uwclass.layer2
WHERE srvr_id NOT IN (
SELECT srvr_id
FROM uwclass. servers
MINUS
SELECT srvr_id
FROM uwclass.serv_inst);
DECLARE
vClobIn CLOB := 'SELECT * FROM uwclass.table_join';
vClobOut CLOB;
BEGIN
dbms_utility.expand_sql_text(vClobIn, vClobOut);
dbms_output.put_line(vClobOut);
END;
/
SELECT "A1"."SRVR_ID" "SRVR_ID" FROM (SELECT DISTINCT "A2"."SRVR_ID" "SRVR_ID"
FROM (SELECT "A3"."SRVR_ID" "SRVR_ID","A3"."NETADDRESS" "NETADDRESS" FROM
(SELECT "A4"."SRVR_ID"
"SRVR_ID","A4"."NETWORK_ID" "NETWORK_ID","A4"."STATUS"
"STATUS","A4"."LATITUDE" "LATITUDE","A4"."LONGITUDE"
"LONGITUDE","A4"."NETADDRESS" "NETADDRESS" FROM "UWCLASS"."SERVERS" "A4")
"A3" WHERE "A3"."STATUS"='Y') "A2" WHERE "A2"."SRVR_ID"<>ALL ( (SELECT
"A7"."SRVR_ID" "SRVR_ID" FROM "UWCLASS"."SERVERS" "A7")MINUS (SELECT
"A6"."SRVR_ID" "SRVR_ID" FROM
"UWCLASS"."SERV_INST" "A6"))) "A1"
PL/SQL procedure successfully completed.
set serveroutput on
DECLARE
outVal CLOB;
BEGIN
dbms_utility.expand_sql_text('SELECT * FROM all_procedures', outVal);
dbms_output.put_line(outVal);
END;
/ SELECT "A1"."OWNER" "OWNER","A1"."OBJECT_NAME" "OBJECT_NAME","A1"."PROCEDURE_NAME"
"PROCEDURE_NAME","A1"."OBJECT_ID" "OBJECT_ID","A1"."SUBPROGRAM_ID" "SUBPROGRAM_ID","A1"."OVERLOAD"
"OVERLOAD","A1"."OBJECT_TYPE" "OBJECT_TYPE","A1"."AGGREGATE"
"AGGREGATE","A1"."PIPELINED" "PIPELINED","A1"."IMPLTYPEOWNER" "IMPLTYPEOWNER","A1"."IMPLTYPENAME"
"IMPLTYPENAME","A1"."PARALLEL" "PARALLEL","A1"."INTERFACE"
"INTERFACE","A1"."DETERMINISTIC" "DETERMINISTIC","A1"."AUTHID" "AUTHID","A1"."RESULT_CACHE"
"RESULT_CACHE","A1"."ORIGIN_CON_ID" "ORIGIN_CON_ID","A1"."POLYMORPHIC"
"POLYMORPHIC" FROM (SELECT "A2"."OWNER" "OWNER","A2"."OBJECT_NAME" "OBJECT_NAME","A2"."PROCEDURE_NAME"
"PROCEDURE_NAME","A2"."OBJECT_ID" "OBJECT_ID","A2"."SUBPROGRAM_ID" "SUBPROGRAM_ID","A2"."OVERLOAD"
"OVERLOAD","A2"."OBJECT_TYPE" "OBJECT_TYPE","A2"."AGGREGATE"
"AGGREGATE","A2"."PIPELINED" "PIPELINED","A2"."IMPLTYPEOWNER" "IMPLTYPEOWNER","A2"."IMPLTYPENAME"
"IMPLTYPENAME","A2"."PARALLEL" "PARALLEL","A2"."INTERFACE"
"INTERFACE","A2"."DETERMINISTIC" "DETERMINISTIC","A2"."AUTHID"
"AUTHID","A2"."RESULT_CACHE" "RESULT_CACHE","A2"."ORIGIN_CON_ID" "ORIGIN_CON_ID","A2"."POLYMORPHIC"
"POLYMORPHIC" FROM
"SYS"."INT$DBA_PROCEDURES" "A2" WHERE "A2"."OWNER"=SYS_CONTEXT('USERENV','CURRENT_USER')
OR EXISTS (SELECT NULL "NULL" FROM (SELECT "A4"."PRIV_NUMBER" "PRIV_NUMBER","A4"."SCOPE"
"SCOPE","A4"."CON_ID" "CON_ID" FROM (SELECT "A5"."PRIV_NUMBER" "PRIV_NUMBER","A5"."SCOPE"
"SCOPE","A5"."CON_ID" "CON_ID" FROM (SELECT "A6"."INST_ID" "INST_ID",(-"A6"."KZSPRPRV")
"PRIV_NUMBER",DECODE(BITAND("A6"."KZSPRFLG",7),1,'COMMON',2,'APPLICATION',4,'LOCAL',NULL)
"SCOPE","A6"."CON_ID" "CON_ID" FROM "SYS"."X$KZSPR" "A6") "A5" WHERE
"A5"."INST_ID"=USERENV('INSTANCE')) "A4" WHERE "A4"."CON_ID"=0 OR
"A4"."CON_ID"=4) "A8" WHERE "A8"."PRIV_NUMBER"=(-144) OR "A8"."PRIV_NUMBER"=(-141)) OR
OBJ_ID("A2"."OWNER","A2"."OBJECT_NAME","A2"."OBJECT_TYPE#","A2"."OBJECT_ID")=ANY
(SELECT "A7"."OBJ#" "OBJ#" FROM "SYS"."OBJAUTH$" "A7" WHERE
"A7"."GRANTEE#"=ANY (SELECT
"A9"."KZSROROL" "KZSROROL" FROM (SELECT "A3"."ADDR" "ADDR","A3"."INDX" "INDX","A3"."INST_ID"
"INST_ID","A3"."CON_ID" "CON_ID","A3"."KZSROROL" "KZSROROL","A3"."KZSROFLG"
"KZSROFLG"
FROM "SYS"."X$KZSRO" "A3" WHERE "A3"."CON_ID"=0 OR "A3"."CON_ID"=4) "A9")
AND "A7"."PRIVILEGE#"=12)) "A1"
CREATE OR REPLACE PROCEDURE Log_Errors(i_buff VARCHAR2) IS
g_start_pos INTEGER := 1;
g_end_pos INTEGER;
FUNCTION output_one_line RETURN BOOLEAN IS
BEGIN
g_end_pos := INSTR(i_buff, CHR(10), g_start_pos);
CASE g_end_pos > 0
WHEN TRUE THEN
dbms_output.put_line(SUBSTR(i_buff, g_start_pos,
g_end_pos-g_start_pos));
g_start_pos := g_end_pos+1;
RETURN TRUE;
WHEN FALSE THEN
dbms_output.put_line(SUBSTR(i_buff, g_start_pos,
(LENGTH(i_buff)-g_start_pos)+1));
RETURN FALSE;
END CASE;
END Output_One_Line;
BEGIN
WHILE output_one_line() LOOP
NULL;
END LOOP;
END Log_Errors;
/
set doc off
set feedback off
set echo off
CREATE OR REPLACE PROCEDURE P0 IS
xcpt EXCEPTION;
pragma exception_init (xcpt, -1476);
BEGIN
RAISE xcpt;
END P0;
/
CREATE OR REPLACE PROCEDURE P1 IS
BEGIN
P0();
END P1;
/
CREATE OR REPLACE PROCEDURE P2 IS
BEGIN
P1();
END P2;
/
CREATE OR REPLACE PROCEDURE P3 IS
BEGIN
P2();
END P3;
/
CREATE OR REPLACE PROCEDURE P4 IS
BEGIN
P3();
END P4;
/
CREATE OR REPLACE PROCEDURE P5 IS
BEGIN
P4();
END P5;
/
CREATE OR REPLACE PROCEDURE top_nolog IS
BEGIN
P5();
END top_nolog;
/
CREATE OR REPLACE PROCEDURE top_logging IS
/* SQLERRM, in principle, gives the same info as Format_Error_Stack. But SQLERRM is subject to some length limits, while Format_Error_Stack is not. */
BEGIN
P5();
EXCEPTION
WHEN OTHERS THEN
log_errors('Error_Stack...' || CHR(10) ||
dbms_utility.format_error_stack());
Log_Errors('Error_Backtrace...' || CHR(10) ||
dbms_utility.format_error_backtrace());
dbms_output.put_line('----------');
END top_logging;
/
set serveroutput on
exec top_nolog;
/*
ERROR at line 1:
ORA-01476: divisor is equal to zero
ORA-06512: at "U.P0", line 4
ORA-06512: at "U.P1", line 3
ORA-06512: at "U.P2", line 3
ORA-06512: at "U.P3", line 3
ORA-06512: at "U.P4", line 2
ORA-06512: at "U.P5", line 2
ORA-06512: at "U.TOPNOLOG", line 3
*/
exec top_logging
/* Error_Stack...
ORA-01476: divisor is equal to zero
Error_Backtrace...
ORA-06512: at "U.P0", line 4
ORA-06512: at "U.P1", line 3
ORA-06512: at "U.P2", line 3
ORA-06512: at "U.P3", line 3
ORA-06512: at "U.P4", line 2
ORA-06512: at "U.P5", line 2
ORA-06512: at "U.TOP_LOGGING", line 6
---------- */
/* ORA-06512: Cause: Backtrace message as the stack is unwound by unhandled exceptions. */
CREATE OR REPLACE FUNCTION test(inval VARCHAR2) RETURN VARCHAR2 IS
shortstr VARCHAR2(5);
BEGIN
shortstr := inval;
RETURN shortstr;
EXCEPTION
WHEN OTHERS THEN
dbms_output.put_line(dbms_utility.format_error_stack());
END;
/
set serveroutput on
SELECT test('ABCDE') FROM dual;
SELECT test('ABCDEF') FROM dual;
Returns the value of a specified initialization parameter
Deprecated as of 12.2: Oracle recommends querying v$parameter directly
dbms_utility.get_parameter_value (
parnam IN VARCHAR2,
interval IN OUT BINARY_INTEGER,
strval IN OUT VARCHAR2,
listno IN BINARY_INTEGER DEFAULT 1)
RETURN BINARY_INTEGER;
set serveroutput on
DECLARE
i BINARY_INTEGER;
intval BINARY_INTEGER;
pname v_$parameter.name%TYPE;
strval v_$parameter.value%TYPE;
x BINARY_INTEGER;
BEGIN
pname := 'optimizer_adaptive_plans';
x := dbms_utility.get_parameter_value(pname, intval, strval);
IF x = 0 THEN -- integer or boolean
dbms_output.put_line('IntVal: ' || TO_CHAR(intval));
ELSE
dbms_output.put_line('StrVal: ' || strval);
dbms_output.put_line('IntVal: ' || TO_CHAR(intval));
END IF;
END;
/ IntVal: 1
PL/SQL procedure successfully completed.
SELECT type, value
FROM gv$parameter
WHERE name = 'optimizer_adaptive_plans';
TYPE VALUE
----- ------
1 TRUE
DECLARE
i BINARY_INTEGER;
intval BINARY_INTEGER;
pname v_$parameter.name%TYPE;
strval v_$parameter.value%TYPE;
x BINARY_INTEGER;
BEGIN
pname := 'utl_file_dir';
x := dbms_utility.get_parameter_value(pname, intval, strval);
IF x = 0 THEN -- integer or boolean
dbms_output.put_line('IntVal: ' || TO_CHAR(intval));
ELSE
dbms_output.put_line('StrVal: ' || strval);
dbms_output.put_line('IntVal: ' || TO_CHAR(intval));
END IF;
END;
/
DECLARE
*
ERROR at line 1:
ORA-20000: get_parameter_value: invalid or unsupported parameter "utl_file_dir"
ORA-06512: at "SYS.DBMS_UTILITY", line 140
ORA-06512: at "SYS.DBMS_UTILITY", line 130
ORA-06512: at line 9
Used to define a constant of type
number_array which serves as default value when an input parameter of type
number_array is not supplied. The function is not needed when an
associative array constructor is provided by the PL/SQL.
dbms_utility.is_bit_set(r IN RAW, n IN NUMBER) RETURN NUMBER;
SELECT global_tran_fmt, global_foreign_id, branch_id
FROM sys.pending_trans$ tran, sys.pending_sessions$ sess
WHERE tran.local_tran_id = sess.local_tran_id
AND tran.state != 'collecting'
AND dbms_utility.is_bit_set(tran.session_vector, sess.session_id)=1;
Demo submitted by Stan Hartin for the library
conn uwclass/uwclass@pdbdev
CREATE TABLE bunch_of_flags (
daylist VARCHAR2(8) NOT NULL);
INSERT INTO bunch_of_flags (daylist) VALUES ('11111111');
INSERT INTO bunch_of_flags (daylist) VALUES ('11111000');
INSERT INTO bunch_of_flags (daylist) VALUES ('00000111');
COMMIT;
col raw_daylist format a20
col 29 format 999
col 25 format 999
col 21 format 999
col 17 format 999
col 13 format 999
col 09 format 999
col 05 format 999
col 01 format 999
Resolves the given name, including synonym translation and authorization checking as necessary
dbms_utility.name_resolve (
name IN VARCHAR2,
context IN NUMBER, -- integer from 0 to 9
schema OUT VARCHAR2,
part1 OUT VARCHAR2,
part2 OUT VARCHAR2,
dblink OUT VARCHAR2,
part1_type OUT NUMBER,
object_number OUT NUMBER);
context 0 = table
context 1 = function, procedure, package
context 2 = sequence
context 3 = trigger
context 4 = java store
context 5 = java resource
context 6 = java class
context 7 = type
context 8 = java shared data
context 9 = index
Metalink Note 1008700.6 states that it only works properly for procedures, functions and packages
set serveroutput on
DECLARE
s VARCHAR2(30);
p1 VARCHAR2(30);
p2 VARCHAR2(30);
d VARCHAR2(30);
o NUMBER(10);
ob NUMBER(10);
BEGIN
dbms_utility.name_resolve('UWCLASS.PERSON.SSN', 2, s, p1, p2, d, o, ob);
Calls the parser to parse the given name as "a [. b [. c ]][@ dblink ]". It strips double quotes, or converts to uppercase if there are no quotes.
It ignores comments of all sorts, and does no semantic analysis. Missing values are left as NULL.
dbms_utility.name_tokenize
name IN VARCHAR2,
a OUT VARCHAR2,
b OUT VARCHAR2,
c OUT VARCHAR2,
dblink OUT VARCHAR2,
nextpos OUT BINARY_INTEGER);
set serveroutput on
DECLARE
a VARCHAR2(30);
b VARCHAR2(30);
c VARCHAR2(30);
d VARCHAR2(30);
i BINARY_INTEGER;
BEGIN
dbms_utility.name_tokenize('UWCLASS.PERSON.SSN', a, b, c, d, i);
dbms_output.put_line('Owner: ' || a);
dbms_output.put_line('Table: ' || b);
dbms_output.put_line('Column: ' || c);
dbms_output.put_line('Link: ' || d);
END;
/
CREATE OR REPLACE PROCEDURE testproc IS
i PLS_INTEGER;
BEGIN
SELECT COUNT(*)
INTO i
FROM test;
END testproc;
/
SELECT object_id, object_name
FROM user_objects
WHERE status = 'INVALID';
ALTER TABLE test
MODIFY (testcol VARCHAR2(25));
SELECT object_id, object_name
FROM user_objects
WHERE status = 'INVALID';
exec dbms_utility.validate(63574);
SELECT object_id, object_name
FROM user_objects
WHERE status = 'INVALID';
Overload 2
dbms_utility.validate(
owner IN VARCHAR2,
objname IN VARCHAR2,
namespace IN NUMBER, -- namespace field from obj$
edition IN VARCHAR2 := SYS_CONTEXT('USERENV','CURRENT_EDITION_NAME'));
conn uwclass/uwclass@pdbdev
CREATE TABLE test (
testcol VARCHAR2(20));
CREATE OR REPLACE PROCEDURE testproc IS
i PLS_INTEGER;
BEGIN
SELECT COUNT(*)
INTO i
FROM test;
END testproc;
/
SELECT object_id, object_name
FROM user_objects
WHERE status = 'INVALID';
ALTER TABLE test
MODIFY (testcol VARCHAR2(25));
SELECT object_id, object_name
FROM user_objects
WHERE status = 'INVALID';
Waits until all transactions (other than the caller's own) that have locks on the listed tables and began prior to the specified SCN have either committed or been rolled back
dbms_utility.wait_on_pending_dml(
tables IN VARCHAR2,
timeout IN BINARY_INTEGER,
scn IN OUT NUMBER)
RETURN BOOLEAN;
Note:
$if utl_ident.is_oracle_server $then
function wait_on_pending_dml(tables IN VARCHAR2, timeout IN BINARY INTEGER,
scn in out number)
return boolean;
$else
/* wait_on_pending_dml is not supported */
$end
set serveroutput on
DECLARE
outscn NUMBER;
BEGIN
IF dbms_utility.wait_on_pending_dml('UWCLASS.SERVERS,UWCLASS.SERV_INST', 2, outscn) THEN
dbms_output.put_line('TRUE');
ELSE
dbms_output.put_line('FALSE');
END IF;
END;
/