Skip to Main Content
  • Questions
  • Delete a table from another schema after fetch cursor

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, Prasanna.

Asked: June 24, 2017 - 3:24 pm UTC

Last updated: June 28, 2017 - 1:33 am UTC

Version: 11.2.04.

Viewed 1000+ times

You Asked

Hi Guys,

Iam fairly new to oracle and was asked a question in an interview about

what happens when a table from another schema gets deleted by an user while the same table was used in a cursor by another user and the deletion happens before fetching the cursor and after opening the cursor.

I honestly do not know whether the question is valid at all...i know fr a fact that data consistency is one of the features of the database.I would like to think the cursor would still execute. Correct me if am wrong.

and thank you guys for the valuable service and keeping askTom the way it was when Mr.Tom Kyte was there.

Sample Code

</>declare
TYPE NameList IS TABLE OF hr.countries%ROWTYPE;
names NameList;
cursor C is select * from HR.countries;
begin
open C;
--table HR.countries gets deleted at this moment---
FETCH c BULK COLLECT INTO names;
null;
Close C;

end;</>


and Connor said...

You are correct, when you open a cursor, the data is effectively "already known" as at that point in time.

We can easily prove this even in a single session, eg

SQL> create table t as select * from scott.emp;

Table created.

SQL>
SQL> select * from t;

     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7369 SMITH      CLERK           7902 17-DEC-80        800                    20
      7499 ALLEN      SALESMAN        7698 20-FEB-81       1600        300         30
      7521 WARD       SALESMAN        7698 22-FEB-81       1250        500         30
      7566 JONES      MANAGER         7839 02-APR-81       2975                    20
      7654 MARTIN     SALESMAN        7698 28-SEP-81       1250       1400         30
      7698 BLAKE      MANAGER         7839 01-MAY-81       2850                    30
      7782 CLARK      MANAGER         7839 09-JUN-81       2450                    10
      7788 SCOTT      ANALYST         7566 09-DEC-82       3000                    20
      7839 KING       PRESIDENT            17-NOV-81       5000                    10
      7844 TURNER     SALESMAN        7698 08-SEP-81       1500                    30
      7876 ADAMS      CLERK           7788 12-JAN-83       1100                    20
      7900 JAMES      CLERK           7698 03-DEC-81        950                    30
      7902 FORD       ANALYST         7566 03-DEC-81       3000                    20
      7934 MILLER     CLERK           7782 23-JAN-82       1300                    10

14 rows selected.

SQL>
SQL> variable r refcursor
SQL> exec open :r for select * from t;

--
-- so I've opened the cursor when t has 1 rows,
-- Now I can delete those rows, and even commit that delete
--

PL/SQL procedure successfully completed.

SQL>
SQL> delete from t;

14 rows deleted.

SQL> commit;

Commit complete.

SQL>
SQL> print r

     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7369 SMITH      CLERK           7902 17-DEC-80        800                    20
      7499 ALLEN      SALESMAN        7698 20-FEB-81       1600        300         30
      7521 WARD       SALESMAN        7698 22-FEB-81       1250        500         30
      7566 JONES      MANAGER         7839 02-APR-81       2975                    20
      7654 MARTIN     SALESMAN        7698 28-SEP-81       1250       1400         30
      7698 BLAKE      MANAGER         7839 01-MAY-81       2850                    30
      7782 CLARK      MANAGER         7839 09-JUN-81       2450                    10
      7788 SCOTT      ANALYST         7566 09-DEC-82       3000                    20
      7839 KING       PRESIDENT            17-NOV-81       5000                    10
      7844 TURNER     SALESMAN        7698 08-SEP-81       1500                    30
      7876 ADAMS      CLERK           7788 12-JAN-83       1100                    20
      7900 JAMES      CLERK           7698 03-DEC-81        950                    30
      7902 FORD       ANALYST         7566 03-DEC-81       3000                    20
      7934 MILLER     CLERK           7782 23-JAN-82       1300                    10

14 rows selected.


My rows are still there, because I opened the cursor *before* I did the delete transaction

Is this answer out of date? If it is, please let us know via a Comment

More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library