a strange behavior in Oracle 12.2.0.1 by nested PLSQL cursor

The following block should provide the commands to disable the foreign keys pointing on a table. It works wonderfully in 11.2.0.4 and 12.1.0.2 but not on 12.2.0.1. Does not trigger an error but also no results. You can test it, just replace ‚MYTABLE‘ with a table that has foreign key pointing on it.

DECLARE
  -- table that has Foreignkey pointing on it
  v_tbl_name VARCHAR2(30) := 'MYTABLE';
CURSOR get_massdata_tableinfo
    IS
      SELECT v_tbl_name table_name FROM dual
       
    ;
    CURSOR get_fks(par_target_table user_tables.table_name%TYPE)
    IS
      WITH
      user_constr AS
      (
        SELECT *
         FROM all_constraints
         WHERE owner = sys_context('USERENV', 'CURRENT_SCHEMA')
      )
      SELECT r.constraint_name,
             r.table_name
       FROM user_constr r,
            user_constr t
       WHERE t.table_name = par_target_table
         AND t.constraint_type = 'P'
         AND t.constraint_name = r.r_constraint_name
    ;
BEGIN
  FOR crec IN get_massdata_tableinfo
    LOOP
      --
      dbms_output.put_line('Table Name ' || crec.table_name);
      -- disable FK´s pointing to table
      FOR rec IN get_fks(crec.table_name) --no rows in 12.2.0.1 (but it works in 11.2.0.4 and 12.1.0.2)
      LOOP
        dbms_output.put_line('ALTER TABLE ' || rec.table_name ||
             ' DISABLE CONSTRAINT ' || rec.constraint_name);
        
      END LOOP;
    END LOOP;
    
END;

If I call the SQL directly, then I get records.

WITH
      user_constr AS
      (
        SELECT *
         FROM all_constraints
         WHERE owner = sys_context('USERENV', 'CURRENT_SCHEMA')
      )
      SELECT r.constraint_name,
             r.table_name
       FROM user_constr r,
            user_constr t
       WHERE t.table_name = 'MY_TABLE'
         AND t.constraint_type = 'P'
         AND t.constraint_name = r.r_constraint_name

Is this a bug ?

It looks like the problem is because of the oracle patch 22485591. It works in a 12.2.0.1 without this patch. In addition, a strange thing: When I add the hint no_merge to the following Statement it works also with the path 22485591.

 CURSOR get_fks(par_target_table user_tables.table_name%TYPE)
    IS
      WITH
      user_constr AS
      (
        SELECT /*+ no_merge */ * -- this is very strange
         FROM all_constraints
         WHERE owner = sys_context('USERENV', 'CURRENT_SCHEMA')
      )
      SELECT r.constraint_name,
             r.table_name
       FROM user_constr r,
            user_constr t
       WHERE t.table_name = par_target_table
         AND t.constraint_type = 'P'
         AND t.constraint_name = r.r_constraint_name
    ;

I posted the problem in freelists.org and I get this response from Jonathan Lewis:

——————————
— „deep dive“
——————————
Okay,
I ran your test and got no output on 12.2.01
Traced it (10046 level 4)
Found that the query against all_constraints went parallel and returned no data, so added a /*+ noparallel */ hint to the query, then (belts and braces) „alter session disable parallel query;“
Ran the test again – got the expected result.
It looks like the parallel execution loses the value of sys_context.
I would check whether 12.1.0.2 and 11.2.0.4 ran the query parallel or whether they ran it serially, and if they’re running t serially check what happens if you force it parallel.

—————–
— After the no_merge comment:
—————–

That (ed. the no_merge) may be luck rather than anything else. I just tried the same thing and still saw the problem (and parallel execution).
In your case it’s possible that the presence of the no_merge hint resulted in Oracle materializing the subquery and maybe that made it run serially – i.e. it was about object_statistics rather than functionality.


P.S.  Looking at the execution plans, my 12.2 (corrected from 12.1) is translating all_constraints to a query involving int$int$DBA_CONSTRAINTS, while the 12.1 query is a „more traditional“ massive join of lots of tables – so the base problem seems to start with the appearance of a CDB-mechanism of all_constraints.  (I’m running 12.2. from a PDB, while the 12.1 is non-PDB database)

Diff two tables

In this post I would like to briefly introduce how I dynamically generate a SQL to find diff of two tables.
When optimizing a SQL Statement to get better performance, in most cases is not only enough to add (or remove) a few hints, but you have to rewrite the whole SQL statement. This is too risky and can cause the new statement to produce a very different result. That’s why you have to compare the results of both statements.
One saves the result of the SQL before the optimization in a table e.g. table_a. And the result of SQL after optimization in the table Table_b. The difference is the result of the following SQL:

Select ‘table_a’ src,t.* from (Select * from table_a minus select * from table_b)
Union all
Select ‘table_b’ src,t.* from (Select * from table_b minus select * from table_a)

This will not work if the tables contain LOB objects. You can exclude the LOB objects from the comparison. But if they were quite relevant, you could use a hash function.
The following PL / SQL block dynamically generates the Diff SQL and use the dbms_crypto.hash function:

DECLARE
tbl_a VARCHAR2(30):= 'TABLE_a';
tbl_b VARCHAR2(30):= 'TABLE_b';
cols VARCHAR2(32767);
stmt VARCHAR2(32767);

BEGIN
  FOR rec IN (SELECT * FROM user_tab_columns WHERE table_name = 'JURISTISCHE_PERSON' ORDER BY column_id) LOOP
    cols := cols || CASE WHEN rec.data_type IN ('CLOB','BLOB') THEN 'dbms_crypto.hash( utl_raw.cast_to_raw('||rec.column_name||'), 2) as ' || rec.column_name
    ELSE rec.column_name END||','||CHR(10);
  END LOOP;
  cols := rtrim(cols,','||CHR(10));
  stmt := 'select '''||tbl_a||''' src,t.* from (select '||cols|| ' from ' || tbl_a || ' minus select '||cols|| ' from ' || tbl_b||') t 
           union all 
           select '''||tbl_b||''',t.* from (select '||cols|| ' from ' || tbl_b || ' minus select '||cols|| ' from ' || tbl_a||') t';
  dbms_output.put_line(stmt);
END;

Oracle reading alert log via sql

In many situations, an Oracle developer needs access to the alert log file to explain some problems occurring on the database. Errors that may be logged there are e.g. problems with tablespaces, online / archive log files, deadlocks or Ora-00600 errors. In the event of serious errors, detailed information is logged in trace files. The trace file name is written in the alert file. However, the alert file is located on the Oracle server and the developers usually do not have access to the Oracle server. Well, we are going to see how we can still access the content of this file through SQL.

From my own experience during the installation a new version of our software at the customer. The customer in Germany has a RAC database with two nodes. The database instances were somewhere in France. It was Friday very late and our software aborts when executing an SQL statement. The sessions just disappear without leaving any traces in our software logging. The DBA in France was unfortunately not available at this time (It was quite simply very late on Friday). In the log of our software, I could find nothing relevant. It was clear that the problem has to do with the Oracle Instance. In such cases, it would be very helpful to take look in the alert file for more information.

Then I came up with the following idea (I already knew that something like that is possible, I’ve read in a book): Luckily we had a database user who is allowed to create directories, external table and has select privelige on gv$process and gv$instance.

Why GV$INSTANCE? Because it was a RAC database so several nodes therefore GV$
The Alert file is called (most) alert_SID.log, where SID is instance_name: SELECT instance_name  FROM GV$INSTANCE

Why GV$PROCESS? Because tt was a RAC database so several nodes therefore GV$ With following query you can get the full path on the OS of the alert file.

SELECT DISTINCT INST_ID,SUBSTR(TRACEFILE,1,INSTR(TRACEFILE, '/', -1)) A  FROM GV$PROCESS 

This block conveniently generates the code to create the directories and the tables:

DECLARE
  STMT VARCHAR2(4000) := 'create table 
   alert_log__inst?int? ( msg varchar2(1024) )
organization external (
   type oracle_loader
   default directory dir4alertfile?int?
   access parameters (
      records delimited by newline
   )
   location(''alert_?SID?.log'')
)
reject limit 100000';
BEGIN
  FOR REC IN (SELECT INSTANCE_NAME, P.*
                FROM GV$INSTANCE I
                JOIN (SELECT DISTINCT INST_ID,
                                     SUBSTR(TRACEFILE,
                                            1,
                                            INSTR(TRACEFILE, '/', -1)) A
                       FROM GV$PROCESS) P
                  ON I.INST_ID = P.INST_ID) LOOP
    DBMS_OUTPUT.PUT_LINE('CREATE OR REPLACE directory dir4alertfile' ||
                         REC.INST_ID || ' as ''' || REC.A || '''');
    DBMS_OUTPUT.PUT_LINE(CHR(10) || CHR(10));
    DBMS_OUTPUT.PUT_LINE(REPLACE(REPLACE(STMT, '?int?', REC.INST_ID),
                                 '?SID?',
                                 REC.INSTANCE_NAME));
    DBMS_OUTPUT.PUT_LINE(CHR(10) || CHR(10));
  END LOOP;
END;

generated code:

--first directory (node1)
CREATE OR REPLACE directory dir4alertfile1 as '/u01/app/oracle/diag/rdbms/mydb/INST1/trace/'


--first external table (node1)
create table
   alert_log__inst1 ( msg varchar2(1024) )
organization external (
   type oracle_loader
   default directory dir4alertfile1
   access parameters (
      records delimited by newline
   )
   location('alert_INST1.log')
)
reject limit 100000

--second directory (node2)
CREATE OR REPLACE directory dir4alertfile2 as '/u01/app/oracle/diag/rdbms/mydb/INST2/trace/'


--second external table (node2)
create table
   alert_log__inst2 ( msg varchar2(1024) )
organization external (
   type oracle_loader
   default directory dir4alertfile2
   access parameters (
      records delimited by newline
   )
   location('alert_INST2.log')
)
reject limit 100000

We can use the same to read in the trace files.

Oracle Datapump Issues

ORA-31626: job does not exist

In this passage I would like to talk about my experience with the error „ORA-31626: job does not exist“.

I’ve written a program that exports a few tables using the dbms_datapump package. I implemented these and successfully tested them on the version 11.2.0.4. However, the program has triggered runtime errors at customer as follows:

ERROR in line 1:
ORA-31626: job does not exist
ORA-06512: in „SYS.DBMS_SYS_ERROR“, line 79
ORA-06512: in „SYS.DBMS_DATAPUMP“, line 1137
ORA-06512: in „SYS.DBMS_DATAPUMP“, line 5285
ORA-06512: in line 57

This error surprised me. What is different on customer environment now than on my environment? The program is created by me and the user who runs the program is scripted by me and the customer has the same Oracle version 11.2.0.4! It was not a compile error, it was a runtime error. So my first suspicion was that maybe some ORA-00600 error occurred. In particular, the message „job does not exist“ has confused me. So I requested the customer to check the alert file for error messages. But everything was normal in the alert file!

Well I have no trace………. All I know is that Datapump has to create a master table for all its work when exporting (and importing too). The master table belongs to system user and is created in the default User-tablespace.

I asked the customer if he could create a table with the user and insert some data into it. The answer came quickly. The customer could create the table but could not add any data. He gets the following errors: ora-01950 no privileges on tablespace ‚users‘. For me it was a surprise, but at least the explanation for the problem.

The user is created from a script by myself! The script grants the user „RESOURCE“ role. And I know that in Oracle 11.2.0.4 Quota is hard-coded on tablespaces in this role. It was revealed that the customer revoked this role from my user. After granting quota on Users tablespace to my user the program worked fine.