I’ve just got back from the DOAG conference, and what a fantastic event it was. I know I’m considered a “long time presenter” but this was my very first DOAG conference (not counting the virtual one from last year) and I was blown away by the enthusiasm of the attendees and the organization of the event. I’ll probably do a little video of highlights soon, but today’s post is to answer a question from an attendee that I promised I would get onto as soon as I got home to Perth.
I mentioned in my Flashback talk that when you perform a flashback table command to rewind a data corruption, then in effect we are performing a sequence of DELETE and INSERT commands to put the impacted table back into a state as of the nominated SCN. For example, I traced a command:
SQL> flashback table scott.imm to scn 16330911765838;
Flashback complete.
and within the trace file, you can see the following statements (I’ve cleaned them up a little for readability)
--
-- populate a temporary table with rowids
--
INSERT INTO SYS_TEMP_FBT
SELECT ROWID, SYS_FBT_INSDEL
FROM SCOTT.IMM AS OF SCN 16330911768778
--
-- delete rows that should no longer be there
--
DELETE FROM
(SELECT S.ROWID
FROM SYS_TEMP_FBT T, SCOTT.IMM S
WHERE T.RID = S.ROWID
AND T.ACTION = 'D'
AND T.OBJECT# = : 1
) V
--
-- reinstate rows with a previous state based on the older SCN
--
INSERT INTO SCOTT.IMM
SELECT S.*
FROM SYS_TEMP_FBT T ,
SCOTT.IMM AS OF SCN 16330911768778 S
WHERE T.RID = S.ROWID
AND T.ACTION = 'I'
AND T.OBJECT# = :2
The question that from an attendee was “What if a table has an identity column?”. This is indeed an interesting question, because we can see that in normal operation, you are not allowed to run an INSERT that refers to an identity column
SQL> create table scott.imm
2 ( x int generated always as identity, y varchar2(10) );
Table created.
SQL> insert into scott.imm values (0,'X');
insert into scott.imm values (0,'X')
*
ERROR at line 1:
ORA-32795: cannot insert into a generated always identity column
So what will happen when the internal INSERT command that is needed to run FLASHBACK is executed? Is there a bug lurking just waiting to be discovered?
Let’s find out!
First I’ll load some data into my table which are rows that will be kept after the flashback. Thus they represent the “PRE” state of the table.
SQL> insert into scott.imm (y) values ( 'PRE');
1 row created.
SQL> commit;
Commit complete.
SQL> insert into scott.imm (y) values ( 'PRE');
1 row created.
SQL> commit;
Commit complete.
SQL> insert into scott.imm (y) values ( 'PRE');
1 row created.
SQL> commit;
Commit complete.
SQL> insert into scott.imm (y) values ( 'PRE');
1 row created.
SQL> commit;
Commit complete.
SQL> insert into scott.imm (y) values ( 'PRE');
1 row created.
SQL> commit;
Commit complete.
SQL> insert into scott.imm (y) values ( 'PRE');
1 row created.
SQL> commit;
Commit complete.
Now I’ll take note of the SCN in the database, because this is where I will be flashing back to.
SQL> select dbms_flashback.GET_SYSTEM_CHANGE_NUMBER scn from dual;
SCN
--------------------------------
16330911765838
And now I’ll add some more rows, this time tagged as “POST”, or “after” the intended point of flashback.
SQL> insert into scott.imm (y) values ( 'POST');
1 row created.
SQL> commit;
Commit complete.
SQL> insert into scott.imm (y) values ( 'POST');
1 row created.
SQL> commit;
Commit complete.
SQL> insert into scott.imm (y) values ( 'POST');
1 row created.
SQL> commit;
Commit complete.
SQL> insert into scott.imm (y) values ( 'POST');
1 row created.
SQL> commit;
Commit complete.
SQL> insert into scott.imm (y) values ( 'POST');
1 row created.
SQL> commit;
Commit complete.
SQL> insert into scott.imm (y) values ( 'POST');
1 row created.
SQL> commit;
Commit complete.
In order to flashback a table, I need to allow rows to be relocated (because they are being deleted/re-inserted) so I’ll run an ENABLE ROW MOVEMENT command.
SQL> alter table scott.imm enable row movement;
Table altered.
And now I can run my flashback
SQL> flashback table scott.imm to scn 16330911765838;
Flashback complete.
As we can see, no error occurred, and the table now only contains values the represent the “PRE” flashback state of the table.
SQL> select * from scott.imm;
X Y
-------------------------------- ----------
1 PRE
2 PRE
3 PRE
4 PRE
5 PRE
6 PRE
6 rows selected.
So that’s a good result – an identity column does not cause any problems. But note that we flashed back the table data, not the entire database, so my identity column continues its standard sequential march forward.
SQL> insert into scott.imm (y) values ( 'PRE');
1 row created.
SQL> commit;
Commit complete.
SQL> select * from scott.imm;
X Y
-------------------------------- ----------
1 PRE
2 PRE
3 PRE
4 PRE
5 PRE
6 PRE
13 PRE
7 rows selected.
We do not rewind the sequence back to “7”. We simply continue getting new sequence numbers.
So flashback and identity are perfectly happy together!
*UPDATE*: See the comments below – I spoke too soon!




Leave a reply to Connor McDonald Cancel reply