Skip to content

Instantly share code, notes, and snippets.

@KrashLeviathan
Created August 23, 2021 15:43
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save KrashLeviathan/1c9e29bab33286a8df419758e0cedf26 to your computer and use it in GitHub Desktop.
Save KrashLeviathan/1c9e29bab33286a8df419758e0cedf26 to your computer and use it in GitHub Desktop.
Execute and monitor a long-running Oracle PL/SQL operation
-- Monitoring query (run in a different session than the long-op is running in):
SELECT opname,
target_desc,
sofar,
totalwork,
units,
elapsed_seconds,
time_remaining
FROM v$session_longops
WHERE opname = 'Item Updates';
-- Assuming your long-running PL/SQL operation will be performing some
-- action on the Item table, create a temporary table to track update status.
-- You can delete this table after all the updates are completed.
create table item_op_status from (
select item_id as item_id,
0 as op_status,
systimestamp as update_ts
from item
);
update item_op_status set update_ts = NULL where 1=1;
COMMIT;
-- In SQL Developer, create a new "unshared session" on your current
-- database connection by typing Ctrl + Shift + N, and then execute
-- your long-running PL/SQL operation in it. (Template given below)
DECLARE
-- Op-specific variables here:
--
-- < ... TODO ... >
--
-- Monitoring variables
rindex binary_integer;
slno binary_integer;
totalwork number; -- Total number of structures
worksofar number := 0; -- Number of structures processed
BEGIN
select count(*) into totalwork
from item_op_status
where task_done = 0;
rindex := dbms_application_info.set_session_longops_nohint;
-- For every Item that hasn't been processed...
FOR i IN (
SELECT item_id
FROM item_op_status
WHERE task_done = 0
ORDER BY item_id
) LOOP
BEGIN
-- Update progress for monitoring
worksofar := worksofar + 1;
dbms_application_info.set_session_longops(
rindex => rindex,
slno => slno,
op_name => 'Item Updates',
sofar => worksofar ,
totalwork => totalwork,
target_desc => 'Updating all Item records per ticket ABC-123',
units => 'items'
);
-- Perform Item updates
--
-- < ... TODO ... >
--
-- Mark it as done
update item_op_status
set task_done = 1,
update_ts = systimestamp
where item_id = i.item_id;
COMMIT;
EXCEPTION
WHEN OTHERS THEN
update item_op_status
set task_done = -1,
update_ts = systimestamp
where item_id = i.item_id;
END;
END LOOP;
END;
/
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment