I'm logged on a Oracle XE instance as SYSTEM user. When I try to run an script that create users, tables and constraints I get an ORA-01031
error. The script is as follows:
CREATE USER AA IDENTIFIED BY AA DEFAULT TABLESPACE users TEMPORARY TABLESPACE temp;
CREATE USER BB IDENTIFIED BY BB DEFAULT TABLESPACE users TEMPORARY TABLESPACE temp;
GRANT ALL PRIVILEGES TO AA WITH ADMIN OPTION;
GRANT ALL PRIVILEGES TO BB WITH ADMIN OPTION;
...
CREATE TABLE ...
CREATE INDEX ...
...
ALTER TABLE "BB"."B_TABLE" ADD CONSTRAINT "FK_BB_AA" FOREIGN KEY ("AA_ID")
REFERENCES "AA"."A_TABLE" ("ID") ENABLE; -- this line report the error
It's not possible to to add this constraint on Oracle XE?
First, there should never be a situation where you are granting ALL PRIVILEGES
to a user and particularly not WITH ADMIN OPTION
. That is just a poor way to manage security. In anything approximating a real system, you would want to determine what privileges are actually needed and grant only those privileges.
Second, in order for a foreign key in schema BB
to reference a parent table in AA
, BB
must have the REFERENCE
privilege on the parent table in AA
. Since there is no REFERENCE ANY TABLE
system privilege, you would need to grant BB
the REFERENCE
privilege on AA.A_TABLE
after creating the table but before creating the foreign key.
GRANT REFERENCES ON aa.a_table TO bb;