I was on call last week and I got a ticket about a batch job that was failing on a MERGE statement with an ORA-30926 error. Our support team worked around it by deleting some duplicate rows in a table that was feeding into the MERGE. This week I wanted to go back and try to understand what would cause ORA-30926 errors on MERGE statements.
I read through some blog posts and Oracle support documents relating to ORA-30926 and merge. Then I tried building some simple test scripts to see when you get ORA-30926 on a MERGE. At the end of my search I came back to this simple statement from the 18c SQL Language Reference manual’s description of the MERGE statement:
MERGE is a deterministic statement. You cannot update the same row of the target table multiple times in the same MERGE statement.
I was puzzled by the term “deterministic” but “cannot update the same row…multiple times” seems simple enough. I created test scripts to show whether you can update the same row multiple times with a MERGE: zip
Here are the two test tables:
create table target (a number,b number);
create table source (a number,b number);
Here is data and a MERGE statement that causes the error:
SQL> insert into target values (1,1);
SQL> insert into source values (1,2);
SQL> insert into source values (1,3);
SQL> merge into target
2 using source
3 on (target.a = source.a)
4 when matched then
5 update set target.b=source.b;
using source
*
ERROR at line 2:
ORA-30926: unable to get a stable set of rows in the source tables
This seems very simple. We join the source and target tables on column A with value 1. The merge statement tries to update column B on the target table row twice. It tries to set it to 2 and then to 3. I guess this is where the term “deterministic” comes in. If the merge statement updated B to 2 and 3 which would it do first and which second?
The example above with values 2 and 3 for B makes good sense but I saw some odd behavior when I used source rows with 1 and 2 for the B values of the two rows. With B values of 1 and 2 in this case the MERGE does not get an error:
SQL> insert into target values (1,1);
SQL> insert into source values (1,1);
SQL> insert into source values (1,2);
SQL> merge into target
2 using source
3 on (target.a = source.a)
4 when matched then
5 update set target.b=source.b;
2 rows merged.
SQL> select * from target;
A B
---------- ----------
1 2
This seems to contradict the idea that you cannot update the same row multiple times with a MERGE. In this case it seems like B is updated twice, once to 1 which is what it already was set to and then to 2. I guess this works because B was already set to 1 so the update of B to the same value does not count as an update. It seems like only one update took place and then B ends up set to 2.
This example does not work with a slightly different MERGE statement on Oracle 12.1 or earlier:
SQL> select banner from v$version;
BANNER
--------------------------------------------------------------------------------
Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production
SQL> merge into target
2 using source
3 on (target.a = source.a)
4 when matched then
5 update set target.b=source.b
6 when not matched then
7 insert values (source.a,source.b);
using source
*
ERROR at line 2:
ORA-30926: unable to get a stable set of rows in the source tables
SQL> select * from source;
A B
---------- ----------
1 1
1 2
SQL>
SQL> select * from target;
A B
---------- ----------
1 1
All that I can say based on these two tests is that sometimes an update of a column to the same value counts as an update and sometimes it does not. The preceding example works on 12.2:
SQL> select banner from v$version;
BANNER
--------------------------------------------------------------------------------
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production
SQL> merge into target
2 using source
3 on (target.a = source.a)
4 when matched then
5 update set target.b=source.b
6 when not matched then
7 insert values (source.a,source.b);
2 rows merged.
SQL> select * from source;
A B
---------- ----------
1 1
1 2
SQL>
SQL> select * from target;
A B
---------- ----------
1 2
It all seemed so simple when I read the documentation. Maybe instead of saying:
You cannot update the same row of the target table multiple times in the same MERGE statement.
Instead it should say:
You may not be able to update the same row of the target table multiple times in the same MERGE statement.
We should not count on being able to update the same row multiple times with a single MERGE statement, but clearly there are some cases in which we can. If you are like me and you get paged on a job that fails with ORA-30926 on a MERGE, it makes sense to get rid of the multiple updates on a single row because you most likely have hit a case where it is not allowed.
Bobby
Thanks for this pretty post.
Run into the similar one on 19c, the only difference is I use an extra where clause in the update section to compare values and switch just between 2 values (on/off).
Anyway, it looks like a bug to me, I’d rather prefer ORA-30926 to get raised instead of such kind of non-deterministic behaviour.
Thanks for your comment!
Bobby
I’m trying to kick it through with SR #3-21137080651
If you get a chance let me know what Oracle says. Thanks again for your comments.
So far they’ve come up with alter session set optimizer_features_enable=’12.1.0.2′;
It doesn’t work at all, or at least for setup and version of ours, they’d have found out if they would try out in their own, but they didn’t.
Obviously, they don’t have a clue what’s going on. I’ll keep you posted if anything reasonable happens.
Thank you for the update.
Bobby