documents. git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@25576 248e525c-4dfb-0310-94bc-949c084e9493
139 lines
5.7 KiB
SQL
139 lines
5.7 KiB
SQL
DECLARE
|
|
l_owner VARCHAR2(80) := upper('&1');
|
|
BEGIN
|
|
IF l_owner IN ('SYS','SYSTEM') THEN
|
|
RAISE no_data_found;
|
|
END IF;
|
|
FOR l_cmd IN (SELECT 0
|
|
,'purge '||TYPE||' '||owner||'.'||original_name AS command
|
|
FROM dba_recyclebin
|
|
WHERE owner = l_owner
|
|
AND can_purge = 'YES'
|
|
AND TYPE NOT IN ('INDEX')
|
|
UNION
|
|
SELECT ord
|
|
,command
|
|
FROM (SELECT 1 AS ord
|
|
,'alter table ' || owner || '.' || table_name ||
|
|
' drop constraint ' ||
|
|
constraint_name AS command
|
|
FROM all_constraints
|
|
WHERE owner = l_owner
|
|
AND constraint_type = 'R'
|
|
UNION
|
|
SELECT 2
|
|
,command
|
|
FROM (SELECT 'truncate ' || object_type || ' ' ||
|
|
owner || '.' || object_name AS command
|
|
,object_type
|
|
FROM all_objects
|
|
WHERE owner = l_owner
|
|
AND object_type IN ('TABLE')
|
|
ORDER BY decode(object_type
|
|
,'TABLE'
|
|
,1
|
|
,'VIEW'
|
|
,2
|
|
,'SEQUENCE'
|
|
,3
|
|
,'SYNONYM'
|
|
,4
|
|
,'TYPE'
|
|
,5
|
|
,6))
|
|
UNION
|
|
SELECT 3
|
|
,command
|
|
FROM (SELECT 'drop ' || object_type || ' ' || owner || '.' ||
|
|
object_name ||decode(object_type,'TYPE',' FORCE') AS command
|
|
,object_type
|
|
FROM all_objects
|
|
WHERE owner = l_owner
|
|
AND object_type IN
|
|
('TABLE', 'VIEW', 'SEQUENCE', 'SYNONYM',
|
|
'TYPE')
|
|
ORDER BY decode(object_type
|
|
,'TABLE'
|
|
,1
|
|
,'VIEW'
|
|
,2
|
|
,'SEQUENCE'
|
|
,3
|
|
,'SYNONYM'
|
|
,4
|
|
,'TYPE'
|
|
,5
|
|
,6))
|
|
UNION
|
|
SELECT 4
|
|
,'drop ' || TYPE || ' ' || owner || '.' || NAME AS command
|
|
FROM all_source
|
|
WHERE owner = l_owner
|
|
AND TYPE NOT IN ('PACKAGE BODY', 'TYPE', 'INDEX')
|
|
)
|
|
ORDER BY 1) LOOP
|
|
BEGIN
|
|
dbms_output.put_line(l_cmd.command);
|
|
EXECUTE IMMEDIATE l_cmd.command;
|
|
EXCEPTION
|
|
WHEN OTHERS THEN
|
|
dbms_output.put_line(SQLERRM);
|
|
END;
|
|
END LOOP;
|
|
|
|
-- remove any nested types
|
|
FOR l_cmd IN (SELECT 'drop ' || object_type || ' ' || owner || '.' ||
|
|
object_name ||decode(object_type,'TYPE',' FORCE') AS command
|
|
,object_type
|
|
FROM all_objects
|
|
WHERE owner = l_owner
|
|
AND object_type IN ('TYPE')
|
|
) LOOP
|
|
BEGIN
|
|
dbms_output.put_line(l_cmd.command);
|
|
EXECUTE IMMEDIATE l_cmd.command;
|
|
EXCEPTION
|
|
WHEN OTHERS THEN
|
|
dbms_output.put_line(SQLERRM);
|
|
END;
|
|
END LOOP;
|
|
|
|
FOR l_cmd IN (SELECT 999
|
|
,'purge '||TYPE||' '||owner||'.'||original_name AS command
|
|
FROM dba_recyclebin
|
|
WHERE owner = l_owner
|
|
AND TYPE NOT IN ('INDEX')
|
|
AND can_purge = 'YES'
|
|
) LOOP
|
|
BEGIN
|
|
dbms_output.put_line(l_cmd.command);
|
|
EXECUTE IMMEDIATE l_cmd.command;
|
|
EXCEPTION
|
|
WHEN OTHERS THEN
|
|
dbms_output.put_line(SQLERRM);
|
|
END;
|
|
END LOOP;
|
|
|
|
FOR l_jobs IN (SELECT job
|
|
FROM all_jobs
|
|
WHERE schema_user = l_owner) LOOP
|
|
dbms_job.remove(job => l_jobs.job);
|
|
END LOOP;
|
|
|
|
FOR l_jobs IN (SELECT owner||'.'||job_name AS job_name
|
|
FROM all_scheduler_jobs
|
|
WHERE owner = l_owner) LOOP
|
|
dbms_scheduler.drop_job(job_name => l_jobs.job_name
|
|
,force => TRUE);
|
|
END LOOP;
|
|
|
|
FOR l_schedules IN (SELECT owner||'.'||schedule_name AS schedule_name
|
|
FROM all_scheduler_schedules
|
|
WHERE owner = l_owner) LOOP
|
|
dbms_scheduler.drop_schedule(schedule_name => l_schedules.schedule_name
|
|
,force => TRUE);
|
|
END LOOP;
|
|
|
|
END;
|
|
/
|