A synonym is an alias for a database object (such as a table, view, materialized view, sequence, stored procedure, function, package, type, or user-defined type). A synonym can also be created for another synonym. A synonym is just an alias and does not occupy any storage space. This topic describes the types, characteristics, and privileges of synonyms.
Types
Synonyms are classified into public synonyms and private synonyms.
Public synonyms are part of the PUBLIC group and can be accessed by all users. Private synonyms belong to the owner of the object and can be accessed by other users only after they are explicitly authorized.
Public synonyms are usually created by DBAs. If a regular user wants to create a public synonym, they must have the CREATE PUBLIC SYNONYM system privilege.
Basic characteristics
Synonyms extend the usability of databases, enabling seamless interaction between different database users. They are often used to simplify object access and enhance the security of object access.
Creating synonyms
The CREATE SYNONYM statement is used to create synonyms. The syntax is as follows:
CREATE [ OR REPLACE ] [ PUBLIC ]
SYNONYM [ schema. ]synonym
FOR [ schema. ]object;
Parameter description
| Parameter | Description |
|---|---|
| OR REPLACE | Indicates that if a synonym with the specified name already exists, it will be replaced with the new definition. |
| PUBLIC | Specifies to create a public synonym, which can be used by all users. Users must have the necessary privileges on the base object to use this synonym. During reference resolution, public synonyms are used only when the object reference does not specify a schema. If PUBLIC is not specified, the synonym is private, accessible only within the current schema, and the synonym name must be unique within the current schema. |
| [schema. ]synonym | The schema specifies the user to which the current synonym belongs. If PUBLIC is specified, the user cannot be specified for the synonym. synonym indicates the name of the synonym. |
| [schema. ]object | Indicates the name of the object to which the synonym corresponds. |
After a synonym is created, you can view it in the USER_SYNONYMS, ALL_SYNONYMS, or DBA_SYNONYMS view.
Examples
Create a private synonym.
obclient> CREATE TABLE t1(c1 INT); obclient> CREATE SYNONYM s1 FOR t1; obclient> INSERT INTO s1 VALUES(1); obclient> SELECT * FROM s1; +------+ | c1 | +------+ | 1 | +------+ 1 row in setCreate a public synonym.
obclient> CREATE PUBLIC SYNONYM syn_pub FOR t1; obclient> SELECT * FROM syn_pub; +------+ | c1 | +------+ | 1 | +------+ 1 row in set
Drop a synonym
You can execute the DROP SYNONYM statement to drop a synonym. The syntax is as follows:
DROP [PUBLIC] SYNONYM [ schema. ]synonym;
Parameters
| Parameter | Description |
|---|---|
| PUBLIC | If you specify PUBLIC, the public synonym is dropped. If you do not specify PUBLIC, the private synonym is dropped. |
| [ schema. ]synonym | The schema name. If you specify PUBLIC, you cannot specify the user for the synonym. synonym specifies the name of the synonym. |
Examples
Drop a private synonym.
obclient> DROP SYNONYM test.s1; Query OK, 0 rows affectedDrop a public synonym.
obclient> DROP PUBLIC SYNONYM syn_pub; Query OK, 0 rows affected
Considerations
To create a synonym, you must meet the following privilege requirements:
To create a private synonym in the current user's schema, you must have the
CREATE SYNONYMprivilege.To create a private synonym in a schema other than the current user's, you must have the
CREATE ANY SYNONYMprivilege.To create a
PUBLICsynonym, you must have theCREATE PUBLIC SYNONYMprivilege.You do not need the privilege to access the object for which the synonym is created.
/* Connect to the `SYS` user */
obclient> CREATE USER syn_user IDENTIFIED BY syn_user;
obclient> GRANT CREATE ON syn_user.* TO syn_user;
obclient> GRANT SELECT ON syn_user.* TO syn_user;
/* Connect to the `syn_user` user. The synonym creation fails. */
obclient> CREATE SYNONYM syn_1 FOR t1;
ERROR-00600: internal error code, arguments: -5036, Access denied; you need (at least one of) the CREATE SYNONYM privilege(s) for this operation
/* Connect to the `SYS` user and grant the CREATE SYNONYM privilege. */
obclient> GRANT CREATE SYNONYM ON *.* TO syn_user;
/* Connect to the `syn_user` user. */
obclient> CREATE SYNONYM syn_1 FOR t1;