Options for RESERVING
Clause
If one of the keywords SHARED
or PROTECTED
is omitted, SHARED
is assumed.If the whole FOR
clause is omitted, FOR SHARED READ
is assumed.The names and compatibility of the four access options for reserving tables are not obvious.
|
SHARED READ |
SHARED WRITE |
PROTECTED READ |
PROTECTED WRITE |
SHARED READ |
Yes |
Yes |
Yes |
Yes |
SHARED WRITE |
Yes |
Yes |
No |
No |
PROTECTED READ |
Yes |
No |
Yes |
No |
PROTECTED WRITE |
Yes |
No |
No |
No |
The combinations of these RESERVING
clause flags for concurrent access depend on the isolation levels of the concurrent transactions:
-
SNAPSHOT
isolation-
Concurrent
SNAPSHOT
transactions withSHARED READ
do not affect one other’s access -
A concurrent mix of
SNAPSHOT
andREAD COMMITTED
transactions withSHARED WRITE
do not affect one another’s access, but they block transactions withSNAPSHOT TABLE STABILITY
isolation from either reading from or writing to the specified table(s) -
Concurrent transactions with any isolation level and
PROTECTED READ
can only read data from the reserved tables.Any attempt to write to them will cause an exception -
With
PROTECTED WRITE
, concurrent transactions withSNAPSHOT
andREAD COMMITTED
isolation cannot write to the specified tables.Transactions withSNAPSHOT TABLE STABILITY
isolation cannot read from or write to the reserved tables at all.
-
-
SNAPSHOT TABLE STABILITY
isolation-
All concurrent transactions with
SHARED READ
, regardless of their isolation levels, can read from or write (if inREAD WRITE
mode) to the reserved tables -
Concurrent transactions with
SNAPSHOT
andREAD COMMITTED
isolation levels andSHARED WRITE
can read data from and write (if inREAD WRITE
mode) to the specified tables but concurrent access to those tables from transactions withSNAPSHOT TABLE STABILITY
is blocked whilst these transactions are active -
Concurrent transactions with any isolation level and
PROTECTED READ
can only read from the reserved tables -
With
PROTECTED WRITE
, concurrentSNAPSHOT
andREAD COMMITTED
transactions can read from but not write to the reserved tables.Access by transactions with theSNAPSHOT TABLE STABILITY
isolation level is blocked.
-
-
READ COMMITTED
isolation-
With
SHARED READ
, all concurrent transactions with any isolation level can both read from and write (if inREAD WRITE
mode) to the reserved tables -
SHARED WRITE
allows all transactions inSNAPSHOT
andREAD COMMITTED
isolation to read from and write (if inREAD WRITE
mode) to the specified tables and blocks access from transactions withSNAPSHOT TABLE STABILITY
isolation -
With
PROTECTED READ
, concurrent transactions with any isolation level can only read from the reserved tables -
With
PROTECTED WRITE
, concurrent transactions inSNAPSHOT
andREAD COMMITTED
isolation can read from but not write to the specified tables.Access from transactions inSNAPSHOT TABLE STABILITY
isolation is blocked.
-
Note
|
In Embedded SQL, the |