Oracle® Application Express API Reference Release 3.2 Part Number E12510-01 |
|
|
PDF · Mobi · ePub |
You can use APEX_PLSQL_JOB
package to run PL/SQL code in the background of your application. This is an effective approach for managing long running operations that do not need to complete for a user to continue working with your application.
Topics in this section include:
Call this function to determine whether or not the database is currently in a mode that supports submitting jobs to the APEX_PLSQL_JOB package.
APEX_PLSQL_JOB.JOBS_ARE_ENABLED RETURN BOOLEAN;
None.
The following example shows how to use the JOBS_ARE_ENABLED
function. In the example, if the function returns TRUE
the message 'Jobs are enabled on this database instance' is displayed, otherwise the message 'Jobs are not enabled on this database instance' is displayed.
BEGIN IF APEX_PLSQL_JOB.JOBS_ARE_ENABLED THEN HTP.P('Jobs are enabled on this database instance.'); ELSE HTP.P('Jobs are not enabled on this database instance.'); END IF; END;
Call this procedure to clean up submitted jobs. Submitted jobs stay in the APEX_PLSQL_JOBS
view until either Oracle Application Express cleans out those records, or you call PURGE_PROCESS
to manually remove them.
APEX_PLSQL_JOB.PURGE_PROCESS ( p_job IN NUMBER);
Table 10-1 describes the parameters available in the PURGE_PROCESS
procedure.
Table 10-1 PURGE_PROCESS Parameters
Parameter | Description |
---|---|
|
The job number that identifies the submitted job you wish to purge. |
The following example shows how to use the PURGE_PROCESS
procedure to purge the submitted job identified by a job number of 161. You could also choose to purge all or some of the current submitted jobs by referencing the APEX_PLSQL_JOBS
view.
BEGIN APEX_PLSQL_JOB.PURGE_PROCESS( p_job => 161); END;
Use this procedure to submit background PL/SQL. This procedure returns a unique job number. Because you can use this job number as a reference point for other procedures and functions in this package, it may be useful to store it in your own schema.
APEX_PLSQL_JOB.SUBMIT_PROCESS ( p_sql IN VARCHAR2, p_when IN DATE DEFAULT SYSDATE, p_status IN VARCHAR2 DEFAULT 'PENDING') RETURN NUMBER;
Table 10-2 describes the parameters available in the SUBMIT_PROCESS
function.
Table 10-2 SUBMIT_PROCESS Parameters
Parameter | Description |
---|---|
|
The process you wish to run in your job. This can be any valid anonymous block, for example: 'BEGIN <your code> END;' or 'DECLARE <your declaration> BEGIN <your code> END;' |
p_when |
When you want to run it. The default is SYSDATE which means the job will run as soon as possible. You can also set the job to run in the future, for example:
|
p_status |
Plain text status information for this job. |
The following example shows how to use the SUBMIT_PROCESS
function to submit a background process that will start as soon as possible.
DECLARE l_sql VARCHAR2(4000); l_job NUMBER; BEGIN l_sql := 'BEGIN MY_PACKAGE.MY_PROCESS; END;'; l_job := APEX_PLSQL_JOB.SUBMIT_PROCESS( p_sql => l_sql, p_status => 'Background process submitted'); --store l_job for later reference END;
Use this function to determine how much time has elapsed since the job was submitted.
APEX_PLSQL_JOB.TIME_ELAPSED( p_job IN NUMBER) RETURN NUMBER;
Table 10-3 describes the parameters available in the TIME_ELAPSED
function.
Table 10-3 TIME_ELAPSED Parameters
Parameter | Description |
---|---|
|
The job ID for the job you wish to see how long since it was submitted. |
The following example shows how to use the TIME_ELAPSED
function to get the time elapsed for the submitted job identified by the job number 161.
DECLARE l_time NUMBER; BEGIN l_time := APEX_PLSQL_JOB.TIME_ELAPSED(p_job => 161); END;
Call this procedure to update the status of the currently running job. This procedure is most effective when called from the submitted PL/SQL.
APEX_PLSQL_JOB.UPDATE_JOB_STATUS ( p_job IN NUMBER, p_status IN VARCHAR2);
Table 10-4 describes the parameters available in the UPDATE_JOB_STATUS procedure.
Table 10-4 UPDATE_JOB_STATUS Parameters
Parameter | Description |
---|---|
|
Passed the reserved word JOB. When this code is executed it will have visibility to the job number via the reserved word JOB. |
p_status |
Plain text that you want associated with
|
The following example shows how to use the UPDATE_JOB_STATUS procedure. In this example, note that:
Lines 002 to 010 run a loop that inserts 100 records into the emp table.
APP_JOB
is referenced as a bind variable inside the VALUES
clause of the INSERT
, and specified as the p_job
parameter value in the call to UPDATE_JOB_STATUS
.
APP_JOB
represents the job number which will be assigned to this process as it is submitted to APEX_PLSQL_JOB
. By specifying this reserved item inside your process code, it will be replaced for you at execution time with the actual job number.
Note that this example calls to UPDATE_JOB_STATUS
every ten records, inside the block of code. Normally, Oracle transaction rules dictate updates made inside code blocks will not be seen until the entire transaction is committed. The APEX_PLSQL_JOB.UPDATE_JOB_STATUS
procedure, however, has been implemented in such a way that the update will happen regardless of whether or not the job succeeds or fails. This last point is important for two reasons:
Even if your status shows "100 rows inserted", it does not mean the entire operation was successful. If an error occurred at the time the block of code tried to commit, the user_status column of APEX_PLSQL_JOBS
would not be affected because status updates are committed separately.
Updates are performed autonomously. You can view the job status before the job has completed. This gives you the ability to display status text about ongoing operations in the background as they are happening.
BEGIN FOR i IN 1 .. 100 LOOP INSERT INTO emp(a,b) VALUES (:APP_JOB,i); IF MOD(i,10) = 0 THEN APEX_PLSQL_JOB.UPDATE_JOB_STATUS( P_JOB => :APP_JOB, P_STATUS => i || ' rows inserted'); END IF; APEX_UTIL.PAUSE(2); END LOOP; END;