Skip to Main Content

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, John.

Asked: May 29, 2019 - 7:47 am UTC

Last updated: June 05, 2019 - 12:14 am UTC

Version: 12.1.0.2

Viewed 1000+ times

You Asked

Hi,
I have a question on performing DDL on objects referenced by a synonym; this seems to be inconsistent? For example, if I create a partition in another schema, and then in my schema point a synonym to that object, from my schema I am able to add a new partition to that table by using the synonym alone. However if I try to drop that partition, I am unable to to do without prefixing with the schema. Same for dropping the table etc.

SQL*Plus: Release 10.1.0.5.0 - Production on Wed May 29 08:34:44 2019

Copyright (c) 1982, 2005, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options

SQL> conn myschema
Connected.

SQL> create table xx(a number)
  2  partition by list (a)
  3  (partition p1 values (1));

Table created.

SQL> grant all on xx to apps;

Grant succeeded.

SQL> connect apps
Connected.
SQL> create synonym xx for myschema.xx;

Synonym created.

SQL> alter table xx add partition p2 values (2);

Table altered.

SQL> alter table xx drop partition p2;
alter table xx drop partition p2
*
ERROR at line 1:
ORA-00942: table or view does not exist


SQL> alter table myschema.xx drop partition p2;

Table altered.

SQL> drop table xx;
drop table xx
           *
ERROR at line 1:
ORA-00942: table or view does not exist


SQL> drop table myschema.xx;

Table dropped.

SQL>


Obviously this is intended functionality, however can you point me in the direction of exactly what DDL operations require a schema prefix? And if possible, some background as to why this is the case?

Thanks!

and Connor said...

Well the official line in the doco here is:

https://docs.oracle.com/en/database/oracle/oracle-database/19/sqlrf/CREATE-SYNONYM.html

You can refer to synonyms in the following DML statements: SELECT, INSERT, UPDATE, DELETE, FLASHBACK TABLE, EXPLAIN PLAN, and LOCK TABLE. You can refer to synonyms in the following DDL statements: AUDIT, NOAUDIT, GRANT, REVOKE, and COMMENT.

Anything else is a "bonus" or "database bug" or "documentation bug" depending on our perspective.

"create index" also works :-)

Rating

  (1 rating)

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

Comments

John Keymer, June 03, 2019 - 9:09 am UTC

Thanks Conor, that's good to know because although DDL in stored code is uncommon, for those of us not lucky enough to have 12.2+ with automatic list partitioning (due to non-certification with E-Business Suite), we have to create the partitions as required... which means in theory any code which does that through a synonym *may* break in the future.
Connor McDonald
June 05, 2019 - 12:14 am UTC

Indeed.

More to Explore

Administration

Need more information on Administration? Check out the Administrators guide for the Oracle Database