|
| 1 | +@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ |
| 2 | +@ Please globally replace below "XYZ" schema name with your @ |
| 3 | +@ actual target schema for installation, and make sure that @ |
| 4 | +@ target schema has following privileges: @ |
| 5 | +@ GRANT CREATE JOB TO XYZ; @ |
| 6 | +@ GRANT SELECT ON USER_SCHEDULER_JOB_RUN_DETAILS TO XYZ; @ |
| 7 | +@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ |
| 8 | + |
| 9 | + |
| 10 | +CREATE OR REPLACE PACKAGE XYZ.TPW_SLIM IS |
| 11 | + |
| 12 | + |
| 13 | +---------------------------------------------------------------------------------------------------- |
| 14 | +-- |
| 15 | +-- Copyright 2017 Abel Cheng |
| 16 | +-- This source code is subject to terms and conditions of the Apache License, Version 2.0. |
| 17 | +-- See http://www.apache.org/licenses/LICENSE-2.0. |
| 18 | +-- All other rights reserved. |
| 19 | +-- You must not remove this notice, or any other, from this software. |
| 20 | +-- |
| 21 | +-- Source Path: http://dbparallel.codeplex.com/SourceControl/latest#TaskParallelFoundation/Databases/Oracle/Scripts/3-Packages/TPW_SLIM.pck |
| 22 | +-- Created Date: 2017-01-08 |
| 23 | +-- |
| 24 | +-- Description: This is a slim framework of Task Parallel Programming that purely rely on |
| 25 | +-- Oracle built-in DBMS_SCHEDULER package, mainly provides 2 method-calls: |
| 26 | +-- |
| 27 | +-- tTask_id := XYZ.TPW_SLIM.RUN_ASYNC(sp, arg1, ...); |
| 28 | +-- |
| 29 | +-- ... ... ... -- do something else |
| 30 | +-- |
| 31 | +-- XYZ.TPW_SLIM.WAIT_FOR_EXIT(tTask_id); |
| 32 | +-- |
| 33 | +-- Original Author: Abel Cheng < [email protected]> |
| 34 | +-- Repository: http://dbParallel.codeplex.com |
| 35 | +-- |
| 36 | +---------------------------------------------------------------------------------------------------- |
| 37 | + |
| 38 | + |
| 39 | +PROCEDURE SET_ASYNC_TASK_COMMENT |
| 40 | +( |
| 41 | + inComments VARCHAR2 |
| 42 | +); |
| 43 | + |
| 44 | + |
| 45 | +FUNCTION RUN_ASYNC |
| 46 | +( |
| 47 | + inStored_Procedure VARCHAR2, |
| 48 | + inArgument1_Value VARCHAR2 |
| 49 | +) RETURN VARCHAR2; |
| 50 | + |
| 51 | +FUNCTION RUN_ASYNC |
| 52 | +( |
| 53 | + inStored_Procedure VARCHAR2, |
| 54 | + inArgument1_Value VARCHAR2, |
| 55 | + inArgument2_Value VARCHAR2 |
| 56 | +) RETURN VARCHAR2; |
| 57 | + |
| 58 | +FUNCTION RUN_ASYNC |
| 59 | +( |
| 60 | + inStored_Procedure VARCHAR2, |
| 61 | + inArgument1_Value VARCHAR2, |
| 62 | + inArgument2_Value VARCHAR2, |
| 63 | + inArgument3_Value VARCHAR2 |
| 64 | +) RETURN VARCHAR2; |
| 65 | + |
| 66 | +FUNCTION RUN_ASYNC |
| 67 | +( |
| 68 | + inStored_Procedure VARCHAR2 |
| 69 | +) RETURN VARCHAR2; |
| 70 | + |
| 71 | + |
| 72 | +PROCEDURE GET_ASYNC_TASK_STATUS |
| 73 | +( |
| 74 | + inTask_id IN VARCHAR2, -- The unique name of background task/job |
| 75 | + outStatus OUT VARCHAR2, |
| 76 | + outError_number OUT PLS_INTEGER, |
| 77 | + outError_message OUT VARCHAR2 |
| 78 | +); |
| 79 | + |
| 80 | + |
| 81 | +PROCEDURE WAIT_FOR_EXIT |
| 82 | +( |
| 83 | + inTask_id VARCHAR2, -- The unique name of background task/job |
| 84 | + inTimeout_Seconds NUMBER := 3600 -- Wait the specified number of seconds for the background task/job to exit |
| 85 | +); |
| 86 | + |
| 87 | + |
| 88 | +END TPW_SLIM; |
| 89 | +/ |
| 90 | +CREATE OR REPLACE PACKAGE BODY XYZ.TPW_SLIM IS |
| 91 | + |
| 92 | + |
| 93 | +tRun_Async_Comments VARCHAR2(128) := 'Asynchronous Execution'; |
| 94 | + |
| 95 | + |
| 96 | +PROCEDURE SET_ASYNC_TASK_COMMENT |
| 97 | +( |
| 98 | + inComments VARCHAR2 |
| 99 | +) AS |
| 100 | +BEGIN |
| 101 | + tRun_Async_Comments := inComments; |
| 102 | +END SET_ASYNC_TASK_COMMENT; |
| 103 | + |
| 104 | + |
| 105 | +FUNCTION GEN_ASYNC_TASK_ID |
| 106 | +RETURN VARCHAR2 AS |
| 107 | +BEGIN |
| 108 | + RETURN '"A-' || RTRIM(UTL_RAW.CAST_TO_VARCHAR2(UTL_ENCODE.BASE64_ENCODE(SYS_GUID())), '=') || '"'; |
| 109 | +END GEN_ASYNC_TASK_ID; |
| 110 | + |
| 111 | + |
| 112 | +FUNCTION RUN_ASYNC |
| 113 | +( |
| 114 | + inStored_Procedure VARCHAR2, |
| 115 | + inArgument1_Value VARCHAR2 |
| 116 | +) RETURN VARCHAR2 AS |
| 117 | +tJob_Name VARCHAR2(32) := GEN_ASYNC_TASK_ID; |
| 118 | +BEGIN |
| 119 | + DBMS_SCHEDULER.CREATE_JOB(job_name => tJob_Name, job_type => 'STORED_PROCEDURE', job_action => inStored_Procedure, number_of_arguments => 1, comments => tRun_Async_Comments); |
| 120 | + DBMS_SCHEDULER.SET_JOB_ARGUMENT_VALUE(job_name => tJob_Name, argument_position => 1, argument_value => inArgument1_Value); |
| 121 | + DBMS_SCHEDULER.ENABLE(tJob_Name); |
| 122 | + RETURN tJob_Name; |
| 123 | +END RUN_ASYNC; |
| 124 | + |
| 125 | + |
| 126 | +FUNCTION RUN_ASYNC |
| 127 | +( |
| 128 | + inStored_Procedure VARCHAR2, |
| 129 | + inArgument1_Value VARCHAR2, |
| 130 | + inArgument2_Value VARCHAR2 |
| 131 | +) RETURN VARCHAR2 AS |
| 132 | +tJob_Name VARCHAR2(32) := GEN_ASYNC_TASK_ID; |
| 133 | +BEGIN |
| 134 | + DBMS_SCHEDULER.CREATE_JOB(job_name => tJob_Name, job_type => 'STORED_PROCEDURE', job_action => inStored_Procedure, number_of_arguments => 2, comments => tRun_Async_Comments); |
| 135 | + DBMS_SCHEDULER.SET_JOB_ARGUMENT_VALUE(job_name => tJob_Name, argument_position => 1, argument_value => inArgument1_Value); |
| 136 | + DBMS_SCHEDULER.SET_JOB_ARGUMENT_VALUE(job_name => tJob_Name, argument_position => 2, argument_value => inArgument2_Value); |
| 137 | + DBMS_SCHEDULER.ENABLE(tJob_Name); |
| 138 | + RETURN tJob_Name; |
| 139 | +END RUN_ASYNC; |
| 140 | + |
| 141 | + |
| 142 | +FUNCTION RUN_ASYNC |
| 143 | +( |
| 144 | + inStored_Procedure VARCHAR2, |
| 145 | + inArgument1_Value VARCHAR2, |
| 146 | + inArgument2_Value VARCHAR2, |
| 147 | + inArgument3_Value VARCHAR2 |
| 148 | +) RETURN VARCHAR2 AS |
| 149 | +tJob_Name VARCHAR2(32) := GEN_ASYNC_TASK_ID; |
| 150 | +BEGIN |
| 151 | + DBMS_SCHEDULER.CREATE_JOB(job_name => tJob_Name, job_type => 'STORED_PROCEDURE', job_action => inStored_Procedure, number_of_arguments => 3, comments => tRun_Async_Comments); |
| 152 | + DBMS_SCHEDULER.SET_JOB_ARGUMENT_VALUE(job_name => tJob_Name, argument_position => 1, argument_value => inArgument1_Value); |
| 153 | + DBMS_SCHEDULER.SET_JOB_ARGUMENT_VALUE(job_name => tJob_Name, argument_position => 2, argument_value => inArgument2_Value); |
| 154 | + DBMS_SCHEDULER.SET_JOB_ARGUMENT_VALUE(job_name => tJob_Name, argument_position => 3, argument_value => inArgument3_Value); |
| 155 | + DBMS_SCHEDULER.ENABLE(tJob_Name); |
| 156 | + RETURN tJob_Name; |
| 157 | +END RUN_ASYNC; |
| 158 | + |
| 159 | + |
| 160 | +FUNCTION RUN_ASYNC |
| 161 | +( |
| 162 | + inStored_Procedure VARCHAR2 |
| 163 | +) RETURN VARCHAR2 AS |
| 164 | +tJob_Name VARCHAR2(32) := GEN_ASYNC_TASK_ID; |
| 165 | +BEGIN |
| 166 | + DBMS_SCHEDULER.CREATE_JOB(job_name => tJob_Name, job_type => 'STORED_PROCEDURE', job_action => inStored_Procedure, number_of_arguments => 0, enabled => TRUE, comments => tRun_Async_Comments); |
| 167 | + RETURN tJob_Name; |
| 168 | +END RUN_ASYNC; |
| 169 | + |
| 170 | + |
| 171 | +PROCEDURE GET_ASYNC_TASK_STATUS |
| 172 | +( |
| 173 | + inTask_id IN VARCHAR2, -- The unique name of background task/job |
| 174 | + outStatus OUT VARCHAR2, |
| 175 | + outError_number OUT PLS_INTEGER, |
| 176 | + outError_message OUT VARCHAR2 |
| 177 | +) AS |
| 178 | +BEGIN |
| 179 | + WITH JLI AS ( |
| 180 | + SELECT |
| 181 | + MAX(LOG_ID) AS LOG_ID |
| 182 | + FROM |
| 183 | + USER_SCHEDULER_JOB_RUN_DETAILS |
| 184 | + WHERE |
| 185 | + STATUS IS NOT NULL |
| 186 | + AND JOB_NAME = TRIM('"' FROM inTask_id) |
| 187 | + ) |
| 188 | + SELECT |
| 189 | + D.STATUS, |
| 190 | + D.ERROR#, |
| 191 | + D.ADDITIONAL_INFO |
| 192 | + INTO |
| 193 | + outStatus, |
| 194 | + outError_number, |
| 195 | + outError_message |
| 196 | + FROM |
| 197 | + JLI L JOIN |
| 198 | + USER_SCHEDULER_JOB_RUN_DETAILS D |
| 199 | + ON (D.LOG_ID = L.LOG_ID); |
| 200 | +EXCEPTION |
| 201 | + WHEN NO_DATA_FOUND THEN |
| 202 | + NULL; |
| 203 | +END GET_ASYNC_TASK_STATUS; |
| 204 | + |
| 205 | + |
| 206 | +PROCEDURE WAIT_FOR_EXIT |
| 207 | +( |
| 208 | + inTask_id VARCHAR2, -- The unique name of background task/job |
| 209 | + inTimeout_Seconds NUMBER := 3600 -- Wait the specified number of seconds for the background task/job to exit |
| 210 | +) AS |
| 211 | +tExpire_Time DATE := SYSDATE + (inTimeout_Seconds / 86400.0); |
| 212 | +tInterval NUMBER := 0.5; |
| 213 | +tStatus VARCHAR2(32); |
| 214 | +tError_Number PLS_INTEGER; |
| 215 | +tError_Message VARCHAR2(4000); |
| 216 | +BEGIN |
| 217 | + LOOP |
| 218 | + GET_ASYNC_TASK_STATUS(inTask_id, tStatus, tError_Number, tError_Message); |
| 219 | + |
| 220 | + IF tStatus IS NULL THEN |
| 221 | + IF SYSDATE < tExpire_Time THEN |
| 222 | + DBMS_LOCK.SLEEP(tInterval); |
| 223 | + IF tInterval < 1.0 THEN |
| 224 | + tInterval := 1.5; |
| 225 | + END IF; |
| 226 | + ELSE |
| 227 | + RAISE_APPLICATION_ERROR(-20445, 'Background job ' || inTask_id || ' time out'); |
| 228 | + END IF; |
| 229 | + ELSIF tStatus = 'SUCCEEDED' THEN |
| 230 | + EXIT; |
| 231 | + ELSE |
| 232 | + IF tError_Message IS NULL THEN |
| 233 | + tError_Message := 'Background job ' || inTask_id || ' ' || tStatus || ', Error#' || tError_Number; |
| 234 | + END IF; |
| 235 | + |
| 236 | + IF tError_Number BETWEEN 20000 AND 20999 THEN |
| 237 | + RAISE_APPLICATION_ERROR(-tError_Number, tError_Message); |
| 238 | + ELSE |
| 239 | + RAISE_APPLICATION_ERROR(-20449, tError_Message); |
| 240 | + END IF; |
| 241 | + END IF; |
| 242 | + END LOOP; |
| 243 | +END WAIT_FOR_EXIT; |
| 244 | + |
| 245 | + |
| 246 | +END TPW_SLIM; |
| 247 | +/ |
0 commit comments