Oracle8i Supplied Packages Reference Release 8.1.5 A68001-01 |
|
The DBMS_ALERT
package provides support for the asynchronous notification of database events (alerts). By appropriate use of this package and database triggers, an application can cause itself to be notified whenever values of interest in the database are changed.
For example, suppose a graphics tool is displaying a graph of some data from a database table. The graphics tool can, after reading and graphing the data, wait on a database alert (WAITONE
) covering the data just read. The tool automatically wakes up when the data is changed by any other user. All that is required is that a trigger be placed on the database table, which then performs a signal (SIGNAL
) whenever the trigger is fired.
Alerts are transaction-based. This means that the waiting session does not get alerted until the transaction signalling the alert commits.There can be any number of concurrent signallers of a given alert, and there can be any number of concurrent waiters on a given alert.
A waiting application is blocked in the database and cannot do any other work.
Security on this package can be controlled by granting EXECUTE
on this package to selected users or roles. You might want to write a cover package on top of this one that restricts the alert names used. EXECUTE
privilege on this cover package can then be granted rather than on this package.
maxwait constant integer := 86400000; -- 1000 days
The maximum time to wait for an alert (this is essentially forever).
DBMS_ALERT
raises the application error -20000 on error conditions. This table shows the messages and the procedures that can raise them.
The application can register for multiple events and can then wait for any of them to occur using the WAITANY
procedure.
An application can also supply an optional timeout
parameter to the WAITONE
or WAITANY
procedures. A timeout
of 0 returns immediately if there is no pending alert.
The signalling session can optionally pass a message that is received by the waiting session.
Alerts can be signalled more often than the corresponding application wait calls. In such cases, the older alerts are discarded. The application always gets the latest alert (based on transaction commit times).
If the application does not require transaction-based alerts, then the DBMS_PIPE
package may provide a useful alternative.
If the transaction is rolled back after the call to SIGNAL
, then no alert occurs.
It is possible to receive an alert, read the data, and find that no data has changed. This is because the data changed after the prior alert, but before the data was read for that prior alert.
Usually, Oracle is event-driven; this means that there are no polling loops. There are two cases where polling loops can occur:
SET_DEFAULTS
procedure.
WAITANY
procedure. If you use the WAITANY
procedure, and if a signalling session does a signal but does not commit within one second of the signal, then a polling loop is required so that this uncommitted alert does not camouflage other alerts. The polling loop begins at a one second interval and exponentially backs off to 30-second intervals.
Subprogram | Description |
---|---|
REGISTER procedure |
Receives messages from an alert. |
REMOVE procedure |
Disables notification from an alert. |
REMOVEALL procedure |
Removes all alerts for this session from the registration list. |
SET_DEFAULTS procedure |
Sets the polling interval. |
SIGNAL procedure |
Signals an alert (send message to registered sessions). |
WAITANY procedure |
Waits |
WAITONE procedure |
Waits |
This procedure lets a session register interest in an alert. The name of the alert is the IN
parameter. A session can register interest in an unlimited number of alerts. Alerts should be deregistered when the session no longer has any interest, by calling REMOVE
.
DBMS_ALERT.REGISTER ( name IN VARCHAR2);
Parameter | Description |
---|---|
name |
Name of the alert in which this session is interested. |
This procedure enables a session that is no longer interested in an alert to remove that alert from its registration list. Removing an alert reduces the amount of work done by signalers of the alert.
Removing alerts is important because it reduces the amount of work done by signalers of the alert. If a session dies without removing the alert, that alert is eventually (but not immediately) cleaned up.
DBMS_ALERT.REMOVE ( name IN VARCHAR2);
Parameter | Description |
---|---|
name |
Name of the alert (case-insensitive) to be removed from registration list. |
This procedure removes all alerts for this session from the registration list. You should do this when the session is no longer interested in any alerts.
This procedure is called automatically upon first reference to this package during a session. Therefore, no alerts from prior sessions which may have terminated abnormally can affect this session.
This procedure always performs a commit.
DBMS_ALERT.REMOVEALL;
None.
In case a polling loop is required, use the SET_DEFAULTS
procedure to set the polling interval.
DBMS_ALERT.SET_DEFAULTS ( polling_interval IN NUMBER);
Parameter | Description |
---|---|
polling_interval |
Time, in seconds, to sleep between polls. The default interval is five seconds. |
This procedure signals an alert. The effect of the SIGNAL
call only occurs when the transaction in which it is made commits. If the transaction rolls back, then SIGNAL
has no effect.
All sessions that have registered interest in this alert are notified. If the interested sessions are currently waiting, then they are awakened. If the interested sessions are not currently waiting, then they are notified the next time they do a wait call.
Multiple sessions can concurrently perform signals on the same alert. Each session, as it signals the alert, blocks all other concurrent sessions until it commits. This has the effect of serializing the transactions.
DBMS_ALERT.SIGNAL ( name IN VARCHAR2, message IN VARCHAR2);
Call WAITANY
to wait for an alert to occur for any of the alerts for which the current session is registered. The same session that waits for the alert may also first signal the alert. In this case remember to commit after the signal and before the wait; otherwise, DBMS_LOCK
.REQUEST
(which is called by DBMS_ALERT
) returns status 4.
DBMS_ALERT.WAITANY ( name OUT VARCHAR2, message OUT VARCHAR2, status OUT INTEGER, timeout IN NUMBER DEFAULT MAXWAIT);
Table 2-7 WAITANY Procedure Parameters
-20000, ORU-10024: there are no alerts registered.
You must register an alert before waiting.
This procedure waits for a specific alert to occur. A session that is the first to signal an alert can also wait for the alert in a subsequent transaction. In this case, remember to commit after the signal and before the wait; otherwise, DBMS_LOCK
.REQUEST
(which is called by DBMS_ALERT
) returns status 4.
DBMS_ALERT.WAITONE ( name IN VARCHAR2, message OUT VARCHAR2, status OUT INTEGER, timeout IN NUMBER DEFAULT MAXWAIT);
Table 2-8 WAITONE Procedure Parameters
Suppose you want to graph average salaries by department, for all employees. Your application needs to know whenever EMP
is changed. Your application would look similar to this code:
DBMS_ALERT.REGISTER('emp_table_alert'); readagain: /* ... read the emp table and graph it */ DBMS_ALERT.WAITONE('emp_table_alert', :message, :status); if status = 0 then goto readagain; else /* ... error condition */
The EMP
table would have a trigger similar to this:
CREATE TRIGGER emptrig AFTER INSERT OR UPDATE OR DELETE ON emp BEGIN DBMS_ALERT.SIGNAL('emp_table_alert', 'message_text'); END;
When the application is no longer interested in the alert, it makes this request:
DBMS_ALERT.REMOVE('emp_table_alert');
This reduces the amount of work required by the alert signaller. If a session exits (or dies) while registered alerts exist, then they are eventually cleaned up by future users of this package.
The above example guarantees that the application always sees the latest data, although it may not see every intermediate value.