 |
|
ORA-02014: cannot select FOR UPDATE from view
Oracle Tips by Laurent Schneider
|
Laurent
Schneider is considered one of the top Oracle SQL experts and he
is the author of the book "Advanced
Oracle SQL Programming" by Rampant TechPress.
Note: The select for update is not a
good locking
strategy because there are many things that can go wrong. Instead of
select for update, savvy Oracle developers will adopt alternatives
mechanisms like a re-read upon update commit where the transaction re-read the
rows and ensure that it has not changed since the original read.
Question: Suppose we have a table A,
whose primary key has 3 columns, X, Y and Z. The table is to be joined to
itself:
SELECT * FROM
a src INNER JOIN a dst ON src.x=dst.x AND src.y = dst.y
WHERE
src.z = 'source' AND
dst.z = 'dest'
For any given row that has a Z column of text
"source"
There can only be one other row having matching X and Y columns and a Z column
of dest.
The whole of the PK is accounted for, and there either exists a pair of rows, or
there not exists a pair of rows. But this view is not updatable and I get
the error "ORA-02014: cannot select FOR UPDATE from view"
Answer:
You get the ORA-02014 error because you have no foreign key to preserve your
rows, and you cannot define a foreign key
a(decode(z,'source',x),decode(z,'source',y))
references a(decode(z,'dest',x),decode(z,'dest',y)).
However, you could create 2
tables SRC and DEST, and a view A to make your view updatable:
SQL> create table a(
x number, y number, z varchar2(7),
constraint a_pk primary key (x,y,z))
Table created.
SQL> insert into a(x,y,z) values (1,1,'source')
1 row created.
SQL> insert into a(x,y,z) values (1,1,'dest')
1 row created.
SQL> commit
Commit complete.
SQL> SELECT * FROM a
X Y Z
---------- ---------- -------
1 1 dest
1 1 source
2 rows selected.
SQL> create table src (
x number, y number, z varchar2(7),
constraint src_pk primary key (x,y))
Table created.
SQL> create table dest (
x number, y number, z varchar2(7),
constraint dst_pk primary key (x,y),
constraint dst_fk foreign key (x,y) references src(x,y))
Table created.
SQL> insert into src(x,y,z) select x,y,z from a where z='source'
1 row created.
SQL> insert into dest(x,y,z) select x,y,z from a where z='dest'
1 row created.
SQL> drop table a
Table dropped.
SQL> create view a as select x,y,z from src
union all
select x,y,z from dest
View created.
SQL> select * from a
X Y Z
---------- ---------- -------
1 1 source
1 1 dest
2 rows selected.
SQL> update (
select src.x, src.y, src.z, dest.x destx, dest.y desty, dest.z destz
from src join dest on (src.x=dest.x and src.y=dest.y))
set x=9 where y=10
0 rows updated.