Skip to Main Content
  • Questions
  • ORA-00904 Invalid Identifier. Query works in 12c but not in 11g

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, Nikhil.

Asked: September 14, 2016 - 12:31 pm UTC

Last updated: September 15, 2016 - 10:07 pm UTC

Version: 12.1.0.2.0

Viewed 10K+ times! This question is

You Asked

Hi Team,

I have a correlated query, trying to execute it on oracle 11g. The same query executes perfectly fine on 12c but it gives ORA-00904 Invalid Identifier u.col_1 on 11g.

Can someone please explain what's causing the issue in 11g?

SELECT *
FROM table_1 u
WHERE u.col_1 LIKE '%XYZ%'
AND EXISTS (SELECT 1
FROM table_2 c,
(SELECT s.col_1 FROM table_2 s WHERE s.col_1 = u.col_1) dd
WHERE c.col_1 = u.col_1
AND c.col_2 = dd.col_2);

Thanks!!

and Chris said...

You've gone "too deep" with your join to table_2. In 11g you can only reference tables in the query immediately inside/outside your current subquery. 12c lifted this restriction.

To resolve this in 11g, your reference to table_1 u needs to be part of the main exists. Not the subquery within this:

SQL> conn chris/chris@12c
Connected.
SQL> select * from v$version;

BANNER                                                                               CON_ID
-------------------------------------------------------------------------------- ----------
Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production              0
PL/SQL Release 12.1.0.2.0 - Production                                                    0
CORE    12.1.0.2.0      Production                                                                0
TNS for Linux: Version 12.1.0.2.0 - Production                                            0
NLSRTL Version 12.1.0.2.0 - Production                                                    0

Elapsed: 00:00:00.55
SQL> with rws as (
  2    select rownum x, 'X' dummy from dual
  3  )
  4    select * from rws r
  5    where  exists (
  6      select null from dual d, (
  7        select x, dummy from rws s where r.x = s.x
  8      ) s
  9      where  d.dummy = s.dummy
 10      and    s.x = r.x
 11    );

         X D
---------- -
         1 X

SQL> conn chris/chris@11g 
Connected.
SQL> select * from v$version;

BANNER
--------------------------------------------------------------------------------
Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production
PL/SQL Release 11.2.0.4.0 - Production
CORE    11.2.0.4.0      Production
TNS for Linux: Version 11.2.0.4.0 - Production
NLSRTL Version 11.2.0.4.0 - Production

Elapsed: 00:00:00.54
SQL> with rws as (
  2    select rownum x, 'X' dummy from dual
  3  )
  4    select * from rws r
  5    where  exists (
  6      select null from dual d, (
  7        select x, dummy from rws s where r.x = s.x
  8      ) s
  9      where  d.dummy = s.dummy
 10      and    s.x = r.x
 11    );
      select x, dummy from rws s where r.x = s.x
                                       *
ERROR at line 7:
ORA-00904: "R"."X": invalid identifier


SQL>
SQL> with rws as (
  2    select rownum x, 'X' dummy from dual
  3  )
  4    select * from rws r
  5    where  exists (
  6      select null from dual d, (
  7        select x, dummy from rws s
  8      ) s
  9      where  d.dummy = s.dummy
 10      and    s.x = r.x
 11    );

         X D
---------- -
         1 X

SQL>

Rating

  (3 ratings)

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

Comments

A reader, September 14, 2016 - 4:38 pm UTC


Documented

Albert Nelson A, September 15, 2016 - 8:08 am UTC

Is this restriction lifting in 12c a documented one? Can you point to the relevant section?

Connor McDonald
September 15, 2016 - 10:07 pm UTC

I havent seen such a mention in the docs, although its not uncommon in these cases not to (in the same way you probably didnt see a mention in the earlier docs that it was *not* possible).

Connor

Thanks

Albert Nelson A, September 16, 2016 - 9:47 am UTC

Thanks Connor.

As I couldn't find this as a documented behavior, I just wanted to confirm if this feature can be "safely" used from 12c onwards.