General |
Source |
{ORACLE_HOME}/rdbms/admin/dbmsrmad.sql |
First Available |
8.1.5 |
Consumer Group Mapping Constants |
Name |
Data Type |
Value |
client_machine |
VARCHAR2(30) |
'CLIENT_MACHINE' |
client_os_user |
VARCHAR2(30) |
'CLIENT_OS_USER' |
client_program |
VARCHAR2(30) |
'CLIENT_PROGRAM' |
module_name |
VARCHAR2(30) |
'MODULE_NAME' |
module_name_action |
VARCHAR2(30) |
'MODULE_NAME_ACTION' |
oracle_user |
VARCHAR2(30) |
'ORACLE_USER' |
performance_class |
VARCHAR2(30) |
'PERFORMANCE_CLASS' |
service_module |
VARCHAR2(30) |
'SERVICE_MODULE' |
service_module_action |
VARCHAR2(30) |
'SERVICE_MODULE_ACTION' |
service_name |
VARCHAR2(30) |
'SERVICE_NAME' |
|
Dependencies |
dba_rsrc_consumer_groups |
dbms_rmin |
dba_rsrc_consumer_group_privs |
dbms_sql |
dba_rsrc_group_mappings |
dbms_sys_error |
dba_rsrc_mapping_priority |
dbms_sys_sql |
dba_rsrc_plans |
default_consumer_group |
dba_users |
gv_$rsrc_consumer_group |
dbms_assert |
resource_consumer_group$ |
dbms_auto_task_admin |
resource_plan$ |
dbms_auto_task_export |
resource_plan_directive$ |
dbms_prvtrmie |
v_$rsrc_consumer_group_cpu_mth |
dbms_resource_manager_privs |
|
|
Security Model |
Execute is granted to PUBLIC |
|
CALIBRATE_IO (new in 11g ) |
Initiates an I/O calibration
Note: Depending on database size or
available disk this may take a long time
|
dbms_resource_manager.calibrate_io(
num_physical_disks IN PLS_INTEGER DEFAULT 1,
max_latency IN PLS_INTEGER DEFAULT 20,
max_iops OUT PLS_INTEGER,
max_mbps OUT PLS_INTEGER,
actual_latency OUT PLS_INTEGER); |
SELECT pname, pval1
FROM aux_stats$
WHERE sname = 'SYSSTATS_MAIN';
col name format a50
SELECT name, asynch_io
FROM gv$datafile f, gv$iostat_file i
WHERE f.file# = i.file_no
AND filetype_name = 'Data File';
-- asynch io must be configured
SELECT name, value
FROM gv$parameter
WHERE name = 'filesystemio_options';
ALTER SYSTEM SET filesystemio_options = 'SETALL'
SCOPE=SPFILE;
ALTER SYSTEM SET filesystemio_options = 'NONE' SCOPE=SPFILE;
shutdown immediate;
start;
SELECT name, value
FROM gv$parameter
WHERE name = 'filesystemio_options';
set serveroutput on
DECLARE
iops PLS_INTEGER;
mbps PLS_INTEGER;
alat PLS_INTEGER;
BEGIN
dbms_resource_manager.calibrate_io(1,
100, iops, mbps, alat);
dbms_output.put_line('Maximum IOPS: ' || TO_CHAR(iops));
dbms_output.put_line('Maximum MBPS: ' || TO_CHAR(mbps));
dbms_output.put_line('Actual Latency: ' || TO_CHAR(iops));
END;
/
SELECT *
FROM gv$io_calibration_status;
SELECT *
FROM dba_rsrc_io_calibrate; |
|
CLEAR_PENDING_AREA |
Clears the work area for the resource manager |
dbms_resource_manager.clear_pending_area; |
exec dbms_resource_manager.clear_pending_area; |
|
CREATE_CATEGORY (new in 11g) |
Create a new resource consumer group category |
dbms_resource_manager.create_category(
category IN VARCHAR2,
comment IN VARCHAR2); |
col category format a15
col comments format a60
SELECT consumer_group, category, comments
FROM dba_rsrc_consumer_groups
ORDER BY 1;
exec dbms_resource_manager.create_pending_area;
-- this produces an error undoubtedly the result of an internal bug
exec dbms_resource_manager.create_category('UW_CATX',
'Demo Category');
SELECT consumer_group, category, comments
FROM dba_rsrc_consumer_groups
ORDER BY 1;
exec
dbms_resource_manager.update_category('UW_CAT', 'New Comment');
SELECT consumer_group, category, comments
FROM dba_rsrc_consumer_groups
ORDER BY 1;
exec dbms_resource_manager.delete_category('UW_CAT');
SELECT consumer_group, category, comments
FROM dba_rsrc_consumer_groups
ORDER BY 1;
exec dbms_resource_manager.submit_pending_area; |
|
CREATE_CONSUMER_GROUP (new 11g parameter) |
Create entries that define resource consumer groups |
dbms_resource_manager.create_consumer_group(
consumer_group IN VARCHAR2,
comment IN VARCHAR2,
cpu_mth IN VARCHAR2 DEFAULT 'ROUND-ROBIN',
category IN VARCHAR2 DEFAULT 'OTHER');
-- alternate cpu_mth is RUN-TO-COMPLETION |
See Demos Below |
|
CREATE_PENDING_AREA |
Create a work area for changes to resource manager objects |
dbms_resource_manager.create_pending_area; |
See Demos Below |
|
CREATE_PLAN (new 11g parameters) |
Create entries that define resource plans |
dbms_resource_manager.create_plan(
plan IN VARCHAR2,
comment IN VARCHAR2,
cpu_mth IN VARCHAR2 DEFAULT
NULL,
active_sess_pool_mth IN VARCHAR2 DEFAULT 'ACTIVE_SESS_POOL_ABSOLUTE',
parallel_degree_limit_mth IN VARCHAR2 DEFAULT
'PARALLEL_DEGREE_LIMIT_ABSOLUTE',
queueing_mth IN VARCHAR2 DEFAULT 'FIFO_TIMEOUT',
mgmt_mth IN VARCHAR2 DEFAULT 'EMPHASIS',
sub_plan IN BOOLEAN DEFAULT FALSE,
max_iops IN NUMBER DEFAULT NULL,
max_mbps IN NUMBER DEFAULT NULL);
cpu_mth: Use 'EMPHASIS' for multi-level plans and 'RATIO'
for single level plans |
See Demos Below |
|
CREATE_PLAN_DIRECTIVE (new 11g parameters) |
Create resource plan directives |
dbms_resource_mananger.create_plan_directive(
plan IN VARCHAR2,
group_or_subplan IN VARCHAR2,
comment IN VARCHAR2,
cpu_p1 IN NUMBER DEFAULT NULL,
cpu_p2 IN NUMBER DEFAULT NULL,
cpu_p3 IN NUMBER DEFAULT NULL,
cpu_p4 IN NUMBER DEFAULT NULL,
cpu_p5 IN NUMBER DEFAULT NULL,
cpu_p6 IN NUMBER DEFAULT NULL,
cpu_p7 IN NUMBER DEFAULT NULL,
cpu_p8 IN NUMBER DEFAULT NULL,
active_sess_pool_p1 IN NUMBER DEFAULT NULL,
queueing_p1 IN NUMBER DEFAULT NULL,
parallel_degree_limit_p1 IN NUMBER DEFAULT NULL,
switch_group IN VARCHAR2 DEFAULT NULL,
switch_time IN NUMBER DEFAULT NULL,
switch_estimate IN BOOLEAN DEFAULT FALSE,
max_est_exec_time IN NUMBER DEFAULT NULL,
undo_pool IN NUMBER DEFAULT NULL,
max_idle_time IN NUMBER DEFAULT NULL,
max_idle_blocker_time IN NUMBER DEFAULT NULL,
switch_time_in_call IN NUMBER DEFAULT NULL,
mgmt_p1 IN NUMBER DEFAULT NULL,
mgmt_p2 IN NUMBER DEFAULT NULL,
mgmt_p3 IN NUMBER DEFAULT NULL,
mgmt_p4 IN NUMBER DEFAULT NULL,
mgmt_p5 IN NUMBER DEFAULT NULL,
mgmt_p6 IN NUMBER DEFAULT NULL,
mgmt_p7 IN NUMBER DEFAULT NULL,
mgmt_p8 IN NUMBER DEFAULT NULL,
switch_io_megabytes IN NUMBER DEFAULT NULL,
switch_io_reqs IN NUMBER DEFAULT NULL,
switch_for_call IN BOOLEAN DEFAULT NULL); |
See Demos Below |
|
CREATE_SIMPLE_PLAN (new 11g parameters) |
Create a single-level resource plan containing up to eight consumer groups in one step |
dbms_resource_manager.create_simple_plan(
simple_plan IN VARCHAR2 DEFAULT NULL,
consumer_group1 IN VARCHAR2 DEFAULT NULL,
group1_cpu IN NUMBER DEFAULT NULL, -- deprecated parameter
consumer_group2 IN VARCHAR2 DEFAULT NULL,
group2_cpu IN NUMBER DEFAULT NULL, -- deprecated parameter
consumer_group3 IN VARCHAR2 DEFAULT NULL,
group3_cpu IN NUMBER DEFAULT NULL, -- deprecated parameter
consumer_group4 IN VARCHAR2 DEFAULT NULL,
group4_cpu IN NUMBER DEFAULT NULL, -- deprecated parameter
consumer_group5 IN VARCHAR2 DEFAULT NULL,
group5_cpu IN NUMBER DEFAULT NULL, -- deprecated parameter
consumer_group6 IN VARCHAR2 DEFAULT NULL,
group6_cpu IN NUMBER DEFAULT NULL, -- deprecated parameter
consumer_group7 IN VARCHAR2 DEFAULT NULL,
group7_cpu IN NUMBER DEFAULT NULL, -- deprecated parameter
consumer_group8 IN VARCHAR2 DEFAULT NULL,
group8_cpu IN NUMBER DEFAULT NULL, -- deprecated parameter
group1_percent IN NUMBER DEFAULT NULL,
group2_percent IN NUMBER DEFAULT NULL,
group3_percent IN NUMBER DEFAULT NULL,
group4_percent IN NUMBER DEFAULT NULL,
group5_percent IN NUMBER DEFAULT NULL,
group6_percent IN NUMBER DEFAULT NULL,
group7_percent IN NUMBER DEFAULT NULL,
group8_percent IN NUMBER DEFAULT NULL); |
TBD |
|
DELETE_CATEGORY (new in 11g) |
Delete an existing resource consumer group category |
dbms_resource_manager.delete_category(category IN VARCHAR2); |
See CREATE_CATEGORY Demo Above |
|
DELETE_CONSUMER_GROUP |
Delete entries that define resource consumer groups |
dbms_resource_manager.delete_consumer_group(consumer_group IN VARCHAR2); |
exec
dbms_resource_manager.delete_consumer_group('Workers'); |
|
DELETE_PLAN |
Deletes the specified plan as well as all the plan directives to which it refers |
dbms_resource_manager.delete_plan(plan IN VARCHAR2); |
exec dbms_resource_manager.delete_plan('UW_PLAN'); |
|
DELETE_PLAN_CASCADE |
Deletes the specified plan as well as well as its descendants (plan directives, subplans, consumer groups)
|
dbms_resource_manager.delete_plan_cascade(plan IN VARCHAR2); |
See Demos Below |
|
DELETE_PLAN_DIRECTIVE |
Delete resource plan directives |
dbms_resource_manager.delete_plan_directive(
plan IN VARCHAR2,
group_or_subplan IN VARCHAR2); |
See Demos Below |
|
SET_CONSUMER_GROUP_MAPPING |
Adds, deletes, or modifies entries that map sessions to consumer groups, based on the session's login and runtime attributes
|
dbms_resource_manager.set_consumer_group_mapping(
attribute IN VARCHAR2,
value IN VARCHAR2,
consumer_group IN VARCHAR2 DEFAULT NULL);
|
TBD |
|
SET_CONSUMER_GROUP_MAPPING_PRI |
Creates the session attribute mapping priority list
The highest priority is 1, the lowest 10 (the docs are incorrect) |
dbms_resource_manager.set_consumer_group_mapping_pri(
explicit IN NUMBER,
oracle_user IN NUMBER,
service_name IN NUMBER,
client_os_user IN NUMBER,
client_program IN NUMBER,
client_machine IN NUMBER,
module_name IN NUMBER,
module_name_action IN NUMBER,
service_module IN NUMBER,
service_module_action IN NUMBER); |
desc
dba_rsrc_mapping_priority
SELECT *
FROM dba_rsrc_mapping_priority;
exec dbms_resource_manager.create_pending_area;
exec dbms_resource_manager.set_consumer_group_mapping_pri(1, 2, 3, 4, 5,
6, 7, 8, 9, 10);
exec dbms_resource_manager.validate_pending_area;
exec dbms_resource_manager.submit_pending_area;
SELECT *
FROM dba_rsrc_mapping_priority;
exec dbms_resource_manager.create_pending_area;
exec dbms_resource_manager.set_consumer_group_mapping_pri(1, 7, 6, 9, 8,
10, 5, 4, 3, 2);
exec dbms_resource_manager.validate_pending_area;
exec dbms_resource_manager.submit_pending_area; |
|
SET_INITIAL_CONSUMER_GROUP |
Assigns the initial resource consumer group
for a user: Obsolete |
dbms_resource_manager.set_initial_consumer_group(
user IN VARCHAR2,
consumer_group IN VARCHAR2); |
Deprecated |
|
SUBMIT_PENDING_AREA |
Submits pending changes for the resource manager |
dbms_resource_manager.submit_pending_area; |
See Demos Below |
|
SWITCH_CONSUMER_GROUP_FOR_SESS |
Changes the resource consumer group of a specific session |
dbms_resource_manager.switch_consumer_group_for_sess(
session_id IN NUMBER,
session_serial IN NUMBER,
consumer_group IN VARCHAR2); |
SELECT username, initial_rsrc_consumer_group
FROM dba_users
ORDER BY 1;
col schemaname format a15
col program format a20
SELECT sid, serial#, schemaname, osuser, program
FROM gv$session
WHERE service_name NOT LIKE '%BACK%';
exec dbms_resource_manager.switch_consumer_group_for_sess(147,
1883, 'SYS_GROUP');
SELECT username, initial_rsrc_consumer_group
FROM dba_users
ORDER BY 1;
exec dbms_resource_manager.switch_consumer_group_for_sess(147,
1883, 'DEFAULT_CONSUMER_GROUP'); |
|
SWITCH_CONSUMER_GROUP_FOR_USER |
Changes the resource consumer group for all sessions with a given user name |
dbms_resource_manager.switch_consumer_group_for_user(
user IN VARCHAR2,
consumer_group IN VARCHAR2); |
exec dbms_resource_manager.switch_consumer_group_for_user(
'UWCLASS', 'rpt_writers_grp'); |
|
SWITCH_PLAN |
Sets the current resource manager plan |
dbms_resource_manager.switch_plan(
plan_name IN VARCHAR2,
sid IN VARCHAR2 DEFAULT '*',
allow_scheduler_plan_switches IN BOOLEAN DEFAULT TRUE); |
TBD |
|
UPDATE_CATEGORY
(new in 11g) |
Update an existing resource consumer group category |
dbms_resource_manager.update_category(
category IN VARCHAR2,
new_comment IN VARCHAR2 DEFAULT NULL); |
See CREATE_CATEGORY Demo Above |
|
UPDATE_CONSUMER_GROUP
(new 11g parameters) |
Update entries that define resource consumer groups |
dbms_resource_manager.update_consumer_group(
consumer_group IN VARCHAR2,
new_comment IN VARCHAR2 DEFAULT NULL,
new_cpu_mth IN VARCHAR2 DEFAULT NULL,
new_mgmt_mth IN VARCHAR2 DEFAULT NULL,
new_category IN VARCHAR2 DEFAULT NULL); |
See Demos Below |
|
UPDATE_PLAN (new
11g parameters) |
Update entries that define resource plans |
dbms_resource_manager.update_plan(
plan IN VARCHAR2,
new_comment IN VARCHAR2 DEFAULT NULL,
new_cpu_mth IN VARCHAR2 DEFAULT NULL,
new_active_sess_pool_mth IN VARCHAR2 DEFAULT NULL,
new_parallel_degree_limit_mth IN VARCHAR2 DEFAULT NULL,
new_queueing_mth IN VARCHAR2 DEFAULT
NULL,
new_mgmt_mth
IN VARCHAR2 DEFAULT NULL,
new_sub_plan
IN BOOLEAN DEFAULT FALSE,
new_max_iops
IN NUMBER DEFAULT NULL,
new_max_mbps
IN NUMBER DEFAULT NULL); |
TBD |
|
UPDATE_PLAN_DIRECTIVE
(new 11g parameters) |
Update resource plan directives |
dbms_resource_manager.update_plan_directive(
plan IN VARCHAR2,
group_or_subplan IN VARCHAR2,
new_comment IN VARCHAR2 DEFAULT NULL,
new_cpu_p1 IN NUMBER
DEFAULT NULL,
new_cpu_p2 IN NUMBER
DEFAULT NULL,
new_cpu_p3 IN NUMBER
DEFAULT NULL,
new_cpu_p4 IN NUMBER
DEFAULT NULL,
new_cpu_p5 IN NUMBER
DEFAULT NULL,
new_cpu_p6 IN NUMBER
DEFAULT NULL,
new_cpu_p7 IN NUMBER
DEFAULT NULL,
new_cpu_p8 IN NUMBER
DEFAULT NULL,
new_active_sess_pool_p1 IN NUMBER DEFAULT NULL,
new_queueing_p1 IN NUMBER
DEFAULT NULL,
new_parallel_degree_limit_p1 IN NUMBER DEFAULT NULL,
new_switch_group IN VARCHAR2 DEFAULT NULL,
new_switch_time IN NUMBER
DEFAULT NULL,
new_switch_estimate IN BOOLEAN
DEFAULT FALSE,
new_max_est_exec_time IN NUMBER
DEFAULT NULL,
new_undo_pool IN NUMBER
DEFAULT NULL,
new_max_idle_time IN NUMBER
DEFAULT NULL,
new_max_idle_blocker_time IN NUMBER DEFAULT NULL,
new_switch_time_in_call IN NUMBER DEFAULT
NULL),
new_mgmt_p1
IN NUMBER DEFAULT NULL,
new_mgmt_p2
IN NUMBER DEFAULT NULL,
new_mgmt_p3
IN NUMBER DEFAULT NULL,
new_mgmt_p4
IN NUMBER DEFAULT NULL,
new_mgmt_p5
IN NUMBER DEFAULT NULL,
new_mgmt_p6
IN NUMBER DEFAULT NULL,
new_mgmt_p7
IN NUMBER DEFAULT NULL,
new_mgmt_p8
IN NUMBER DEFAULT NULL,
new_switch_io_megabytes
IN NUMBER DEFAULT NULL,
new_switch_io_reqs
IN NUMBER DEFAULT NULL,
new_switch_for_call
IN BOOLEAN DEFAULT NULL); |
TBD |
|
VALIDATE_PENDING_AREA |
Validates pending changes for the resource manager |
dbms_resource_manager.validate_pending_area; |
See Demo |
|
Demos |
Create Plan 1 Demonstration |
conn / as sysdba
desc dba_users
SELECT username, initial_rsrc_consumer_group
FROM dba_users
ORDER BY 1;
GRANT select ON dba_rsrc_consumer_groups TO uwclass;
-- create pointy-haired boss user
CREATE USER phb
IDENTIFIED BY phb
DEFAULT TABLESPACE uwdata
TEMPORARY TABLESPACE temp
QUOTA 1M ON uwdata;
GRANT create session TO phb;
SELECT username, initial_rsrc_consumer_group
FROM dba_users
ORDER BY 1;
desc dba_rsrc_consumer_group_privs
SELECT *
FROM dba_rsrc_consumer_group_privs;
set linesize 121
col plan format a30
col cpu_method format a10
col comments format a60
desc dba_rsrc_plans
SELECT plan, cpu_method, comments, mandatory
FROM dba_rsrc_plans;
col cpu_method format a15
col consumer_group format a25
col comments format a45
desc dba_rsrc_consumer_groups
SELECT *
FROM dba_rsrc_consumer_groups;
col value format a20
desc dba_rsrc_group_mappings
SELECT *
FROM dba_rsrc_group_mappings;
exec dbms_resource_manager_privs.grant_system_privilege('UWCLASS', 'ADMINISTER_RESOURCE_MANAGER', FALSE);
conn uwclass/uwclass
-- create a pending area
exec dbms_resource_manager.create_pending_area;
-- create two consumer groups: Workers and Managers
exec dbms_resource_manager.create_consumer_group('Workers', 'Those that do actual work');
exec dbms_resource_manager.create_consumer_group('Managers', 'Those that don''t but take all the credit');
SELECT *
FROM dba_rsrc_consumer_groups;
exec dbms_resource_manager.update_consumer_group('Managers', 'The Cartesian products of the IT world');
SELECT *
FROM dba_rsrc_consumer_groups;
-- create resource management plan
exec dbms_resource_manager.create_plan('UW_PLAN','Demo Resource Plan', 'RATIO');
-- create plan directives
exec dbms_resource_manager.create_plan_directive(plan=>'UW_PLAN', group_or_subplan=>'Workers', comment=>'Can Grab All The CPU', cpu_p1=>100);
exec dbms_resource_manager.create_plan_directive(plan=>'UW_PLAN', group_or_subplan=>'Managers', comment=>'Give Managers Little Weight', cpu_p1=>1);
-- validate the pending area
exec dbms_resource_manager.validate_pending_area;
exec dbms_resource_manager.create_plan_directive(plan=>'UW_PLAN', group_or_subplan=>'OTHER_GROUPS', comment=>'Testing', cpu_p2=>0);
-- validate the pending area
exec dbms_resource_manager.validate_pending_area;
-- oops ... go back and redo correctly
-- delete plan directives
exec dbms_resource_manager.delete_plan_directive('UW_PLAN', 'Managers');
-- recreate plan directives
exec dbms_resource_manager.create_plan_directive(plan=>'UW_PLAN', group_or_subplan=>'Managers', comment=>'Infinite Weight', cpu_p1=>0);
-- revalidate the pending area
exec dbms_resource_manager.validate_pending_area;
-- submit the pending area
exec dbms_resource_manager.submit_pending_area;
SELECT plan, cpu_method, comments, status, mandatory
FROM dba_rsrc_plans;
SELECT *
FROM dba_rsrc_consumer_groups;
exec dbms_resource_manager_privs.grant_switch_consumer_group(grantee_name=>'PHB', consumer_group=>'Managers', grant_option=>FALSE);
exec dbms_resource_manager.set_initial_consumer_group(user=> 'SCHEDULE', consumer_group=>'Managers');
alter system set resource_manager_plan = 'UW_PLAN';
conn schedule/schedule
/* So PHB is in a group that should have no CPU. Does this
mean PHB can't do anything?
*/
SELECT COUNT(*) FROM all_tables;
/* PHB is fine. There's plenty of free CPU so even though the group
that PHB group belongs to "looks" like it should have no CPU, that doesn't have any effect in this case.
*/
|
Create Plan 2 Demonstration |
/*
Resource Manager is only effective
(from a CPU point of view)
once CPU utilization starts to max out. Oracle takes the attitude
that if there is spare CPU capacity, there is no need to limit
usage. Only when the resource becomes scarce does Oracle restrict
access.
*/
BEGIN
-- create pending area
dbms_resource_manager.create_pending_area;
dbms_resource_manager.create_plan(plan=>'TEST2',
comment=>'Use 10g Feature');
dbms_resource_manager.create_plan_directive(plan=>'TEST2',
group_or_subplan=>'HAVES', comment=>'Testing', cpu_p1=>100);
dbms_resource_manager.create_plan_directive(plan=>'TEST2',
group_or_subplan=>'NOTS', comment=>'Testing', cpu_p1=>0,
max_est_exec_time=>0);
/*
Prevent the have Managers from running any operation that has
an estimated execution time > 0.
*/
dbms_resource_manager.create_plan_directive(plan=>'TEST2',
group_or_subplan=>'OTHER_GROUPS', comment=>'Testing', cpu_p2=>100);
dbms_resource_manager.validate_pending_area;
dbms_resource_manager.submit_pending_area;
dbms_resource_manager_privs.grant_switch_consumer_group(
grantee_name=>'PHB', consumer_group=>'Managers',
grant_option=>FALSE);
dbms_resource_manager.set_initial_consumer_group(user =>
'SCHEDULE', consumer_group=>'Managers');
END;
/
ALTER SYSTEM SET resource_manager_plan = test2;
conn schedule/schedule
SELECT COUNT(*) FROM huge_table;
ERROR at line 1:
ORA-07455: estimated execution time (56 secs), exceeds limit (0 secs)
/*
However, the problem here is that Oracle kinda rounds *down* the
estimate execution time so providing I'm not being too greedy with my resources, Oracle can be a little lenient...
*/
SELECT COUNT(*) FROM small_table; |
Drop Plan Demonstration |
conn / as sysdba
-- create pending area
exec dbms_resource_manager.create_pending_area;
-- remove admin privilege from uwclass
exec dbms_resource_manager_privs.revoke_system_privilege('UWCLASS', 'ADMINISTER_RESOURCE_MANAGER');
-- delete resource plan
exec dbms_resource_manager.delete_plan_cascade('UW_PLAN');
-- validate pending area
exec dbms_resource_manager.validate_pending_area;
SELECT username, initial_rsrc_consumer_group
FROM dba_users
ORDER BY 1;
-- switch consumer group for user SCHEDULES
exec dbms_resource_manager.switch_consumer_group_for_user('SCHEDULE', 'DEFAULT_CONSUMER_GROUP');
BEGIN
dbms_resource_manager.create_pending_area;
dbms_resource_manager.delete_plan_cascade('UW_PLAN');
dbms_resource_manager.validate_pending_area;
END;
/
-- submit pending area
exec dbms_resource_manager.submit_pending_area;
-- revoke system privilege from user
exec dbms_resource_manager_privs.revoke_system_privilege('UWCLASS'); |