I’ve had to create test data a number of times, including data for tables that had mandatory foreign keys to existing tables. It was not feasible to just create new master rows for my test data; I wanted to refer to a random sample of existing data; but the code that generates the test data had to perform reasonably well, even though it had to pick out some random values from a very large table.
Solution? A combination of the new 10g SAMPLE operator, and DBMS_RANDOM. To illustrate:
(create a “very large table”)
SQL> create table t as
2 select rownum n, dbms_random.string(‘a’,30) v
3 from all_objects;
Table created.
SQL> select count(*) from t;
COUNT(*)
———-
40981
(get a random sample from the table)
SQL> select n, substr(v,1,30) from t sample(0.01)
2 order by dbms_random.value;
N SUBSTR(V,1,30)
———- ——————————
11852 xSsdmFtGqkymbKCFoZwUzNxpJAPwaV
8973 RGyNjqMfVayKdiKFGvLYuAFYUpIbCw
25295 eJJtoieSWtzUTIZXCbOLzmdmWHHPOy
297 hiTxUPYKzWKAjFRYTTfJSSCuOwGGmG
1924 yZucJWgkFviAIeXiSCuNeUuDjClvxt
40646 wMTumPxfBMoAcNtVMptoPchILHTXJa
6 rows selected.
SQL> set serveroutput on
(Get a single value chosen at random)
SQL> declare
2 cursor cur_t is
3 select n from t sample(0.01)
4 order by dbms_random.value;
5 l number;
6 begin
7 open cur_t;
8 fetch cur_t into l;
9 dbms_output.put_line(l);
10 close cur_t;
11* end;
SQL> /
21098
PL/SQL procedure successfully completed.
My test code would open the cursor, fetch as many values as it needed, and then close it. If the cursor ran out of values (e.g. the sample was too small for the desired amount of test data, which varied), my code just re-opened the cursor to fetch another set of random values from the large table.
The reason I sort the sample by dbms_random.value is so that if I only want one value, it is not weighted towards rows found nearer the start of the table.
Note: If I didn’t really care about the sample being picked at random from throughout the table, I could have just selected from the table “where rownum < n".
PL/SQL User’s Guide and Reference (10.2): “4 Using PL/SQL Control Structures – Using the NULL Statement”
“…Note that the use of the NULL statement might raise an unreachable code warning if warnings are enabled.”
Example 4-23 Using NULL as a Placeholder When Creating a Subprogram
CREATE OR REPLACE PROCEDURE award_bonus (emp_id NUMBER, bonus NUMBER) AS
BEGIN — executable part starts here
NULL; — use NULL as placeholder, raises “unreachable code” if warnings enabled
END award_bonus;
/
Indeed, when I compile the above in 10.2 with PL/SQL warnings on, I get PLW-06002 as expected (due to bug 3680132 I get “Message 6002 not found; No message file for product=plsql, facility=PLW” but at least I can look it up in the reference).
“PLW-06002: Unreachable code”
“Cause: Static program analysis determined that some code on the specified line would never be reached during execution.”
I agree that a PL/SQL warning would be desirable in the case where a procedure has nothing but a NULL in it (probably a stub). Correct me if I’m wrong, but if I were to call award_bonus, surely the NULL is “executed” – therefore, it is reachable! A more appropriate warning would be something like “function/procedure does nothing”, or “get back to work you silly mug, you’ve forgotten to finish the code”. Maybe they just couldn’t be bothered making up another warning code.
Jeffrey Kemp
11 February 2006
PL/SQL /
The application I’m working on involves a number of views that provide an interface between two databases that have quite different models. The views implement inserts, updates and deletes via Instead-of triggers.
On one of these views, the update trigger needs to actually do an update and an insert on the source table: it must update the existing row to mark it as “closed”, and then insert a new row to take its place. In this way the view hides the fact that the table keeps a history of changes.
Now, a logical constraint is that there can only be one “open” record for a given entity. Therefore, there can be zero or more “closed” records, and there must be a single “open” record. This constraint, however, has not been implemented on the database (naughty naughty) because our code is perfect and never makes a mistake 😉
This worked perfectly well until our thorough Java guy decided to do some load testing, in which a process would hammer away inserting, updating and deleting the same row over and over again, in multiple concurrent sessions.
This had the result that we ended up seeing lots of “open” records for the entity, which violates the logical constraint described above. “That’s not allowed” I said, and soon realised that the fact that multiple sessions are updating the same row means that even a trigger-based constraint check will not solve the problem, since the triggers cannot see updates from other sessions.
So, we need to have a lock of some sort, so that when one session wants to update an entity, other sessions cannot start updating it as well until the first one is finished. I can’t just lock the row I want to update, because after I’ve updated it, I still need the lock while I insert the new row.
The solution is to use a package supplied with Oracle calls DBMS_LOCK, with which I can request “user-named locks”. This package gives a lot of options but I’m only interested in simple Exclusive locks, so I’ll also create some wrapper procedures.
Easy, right? Well, yeah once you get past a few gotchas.
Try #1:
-- wrapper function to Request a lock; returns a lock handle
FUNCTION request_lock (lock_name IN VARCHAR2) RETURN VARCHAR2 IS
lock_status NUMBER;
lock_handle VARCHAR2(128);
BEGIN
DBMS_LOCK.ALLOCATE_UNIQUE (
lockname => lock_name,
lockhandle => lock_handle,
expiration_secs => 864000); -- 10 days
lock_status := DBMS_LOCK.REQUEST(
lockhandle => lock_handle,
lockmode => DBMS_LOCK.X_MODE, -- eXclusive
timeout => DBMS_LOCK.MAXWAIT, -- wait forever
release_on_commit => TRUE);
IF lock_status > 0 THEN
RAISE_APPLICATION_ERROR(-20000,'request_lock failed: ' || lock_status);
END IF;
RETURN lock_handle;
END request_lock;
-- wrapper to release a lock; call with the lock handle obtained previously
PROCEDURE release_lock (lock_handle IN VARCHAR2) IS
lock_status NUMBER;
BEGIN
lock_status := DBMS_LOCK.RELEASE(
lockhandle => lock_handle);
IF lock_status > 0 THEN
RAISE_APPLICATION_ERROR(-20000,'release_lock failed: ' || lock_status);
END IF;
END release_lock;
--example calling code
...
DECLARE
lock_handle VARCHAR2(128);
BEGIN
lock_handle := request_lock('MYLOCK1');
-- do some stuff
release_lock(lock_handle);
END;
...
The above code “worked” ok (although I hadn’t yet tested to see if it was actually getting the lock) until I started calling it from triggers on the views, when I started getting “ORA-04092: cannot commit in a trigger”. What the? I wasn’t doing any commits in my triggers. I couldn’t find any references to the DBMS_LOCK functions doing commits in the 10g documentation, but I thought, ok let’s make these wrappers Autonomous, so they can commit in peace:
Try #2:
FUNCTION request_lock (lock_name IN VARCHAR2) RETURN VARCHAR2 IS
PRAGMA AUTONOMOUS_TRANSACTION;
lock_status NUMBER;
lock_handle VARCHAR2(128);
BEGIN
DBMS_LOCK.ALLOCATE_UNIQUE (
lockname => lock_name,
lockhandle => lock_handle,
expiration_secs => 864000); -- 10 days
lock_status := DBMS_LOCK.REQUEST(
lockhandle => lock_handle,
lockmode => DBMS_LOCK.X_MODE, -- eXclusive
timeout => DBMS_LOCK.MAXWAIT, -- wait forever
release_on_commit => TRUE);
IF lock_status > 0 THEN
RAISE_APPLICATION_ERROR(-20000,'request_lock failed: ' || lock_status);
END IF;
RETURN lock_handle;
END request_lock;
PROCEDURE release_lock (lock_handle IN VARCHAR2) IS
PRAGMA AUTONOMOUS_TRANSACTION;
lock_status NUMBER;
BEGIN
lock_status := DBMS_LOCK.RELEASE(
lockhandle => lock_handle);
IF lock_status > 0 THEN
RAISE_APPLICATION_ERROR(-20000,'release_lock failed: ' || lock_status);
END IF;
END release_lock;
No good: I got “ORA-06519: active autonomous transaction detected and rolled back”! This didn’t make much sense at the time, but I put a COMMIT in anyway. But of course, this wouldn’t work with the triggers. Anyway, I started experimenting and soon realised that even if I got the wrappers to work, the locks weren’t being made anyway, and I was able to request locks multiple times, which I expected to be impossible if the wrapper was working correctly.
Finally, I logged in as a user with some DBA privileges and read the specification of the SYS.DBMS_LOCK package. The one thing that jumped out at me was a little comment under ALLOCATE_UNIQUE:
“This routine will always do a commit.”
There was my answer. It was the ALLOCATE_UNIQUE that was doing a commit, not REQUEST or RELEASE. And, because I was setting release_on_commit => TRUE in the call to REQUEST, whenever I committed the lock was being released, straight away.
So I changed release_on_commit => FALSE, and moved ALLOCATE_UNIQUE to a separate function (set up as an Autonomous Transaction). Having read a bit more I realised I could make this API nicer to the programmers by allowing the release_lock to accept the lock name instead of requiring them to manage the lock handle. I also improved the error messages.
Try #3:
-- internal function to get a lock handle
-- (private for use by request_lock and release_lock)
FUNCTION get_handle (lock_name IN VARCHAR2) RETURN VARCHAR2 IS
PRAGMA AUTONOMOUS_TRANSACTION;
lock_handle VARCHAR2(128);
BEGIN
DBMS_LOCK.ALLOCATE_UNIQUE (
lockname => lock_name,
lockhandle => lock_handle,
expiration_secs => 864000); -- 10 days
RETURN lock_handle;
END get_handle;
PROCEDURE request_lock (lock_name IN VARCHAR2) IS
lock_status NUMBER;
BEGIN
lock_status := DBMS_LOCK.REQUEST(
lockhandle => get_handle(lock_name),
lockmode => DBMS_LOCK.X_MODE, -- eXclusive
timeout => DBMS_LOCK.MAXWAIT, -- wait forever
release_on_commit => FALSE);
CASE lock_status
WHEN 0 THEN NULL;
WHEN 2 THEN RAISE_APPLICATION_ERROR(-20000,'deadlock detected');
WHEN 4 THEN RAISE_APPLICATION_ERROR(-20000,'lock already obtained');
ELSE RAISE_APPLICATION_ERROR(-20000,'request lock failed: ' || lock_status);
END CASE;
END request_lock;
-- wrapper to release a lock
PROCEDURE release_lock (lock_name IN VARCHAR2) IS
lock_status NUMBER;
BEGIN
lock_status := DBMS_LOCK.RELEASE(
lockhandle => get_handle(lock_name));
IF lock_status > 0 THEN
RAISE_APPLICATION_ERROR(-20000,'release lock failed: ' || lock_status);
END IF;
END release_lock;
--example calling code
...
BEGIN
request_lock('MYLOCK1');
-- do some stuff
release_lock('MYLOCK1');
END;
...
This worked perfectly, even from triggers. I even tried it out with multiple sessions:
Session 1:
exec request_lock('JEFF');
Session 2:
exec request_lock('JEFF');
At this point, session 2 just hung – it was waiting for Session 1 to release the lock.
Session 1:
exec release_lock('JEFF');
Now session 2 returned and had the lock. The same thing happened if I just closed down session 1.
If I changed request_lock to set timeout to some value (e.g. 3 seconds), session 2 would wait for that amount of time, then raise my error message “request lock failed – 1” (1 is the status code when a lock request times out).
I tried it with a deadlock situation, with timeout = MAXWAIT:
Session 1:
exec request_lock('MYLOCKA');
Session 2:
exec request_lock('MYLOCKB');
Session 1:
exec request_lock('MYLOCKB');
At this point session 1 hangs as it waits for session 2 to release the lock.
Session 2:
exec request_lock('MYLOCKA');
This is a deadlock. Both sessions are waiting for a lock held by the other session. After a few seconds Oracle automatically detects the deadlock and picks one session (at random, apparently) and it returns the lock status 2 (my code raises the error message “deadlock detected”). The other session stayed hung, however – it was still waiting, but there was no deadlock.
I tried the above scenario again, but with timeout = 5 seconds. If I executed the request_locks quick enough, I got “deadlock detected” on one session, and the other session eventually timed out.
So, everything works as expected, and the Java guys can hammer away at my views with impunity.
—
UPDATE for Oracle 12.1 and later:
The get_handle function no longer needs to be autonomous, since DBMS_LOCK now provides an autonomous variant of ALLOCATE_UNIQUE:
FUNCTION get_handle (lock_name IN VARCHAR2) RETURN VARCHAR2 IS
lock_handle VARCHAR2(128);
BEGIN
DBMS_LOCK.ALLOCATE_UNIQUE_AUTONOMOUS (
lockname => lock_name,
lockhandle => lock_handle,
expiration_secs => 864000); -- 10 days
RETURN lock_handle;
END get_handle;
https://docs.oracle.com/en/database/oracle/oracle-database/19/arpls/DBMS_LOCK.html#GUID-0D6C0622-05CA-4259-8059-330D512E1574
(thanks to Kim Berg Hansen for the update)