Updated on 2024-08-20 GMT+08:00

CREATE SYNONYM

Description

Creates a synonym object. A synonym is an alias of a database object and is used to record the mapping between database object names. You can use synonyms to access associated database objects.

Precautions

  • The user who creates the synonym will be the owner of the synonym.
  • If the schema name is specified, create a synonym in the specified schema. Otherwise, a synonym is created in the current schema.
  • Database objects that can be accessed using synonyms include tables, views, types, packages, functions, stored procedures, sequences, or other synonyms.
  • To use synonyms, you must have the required permissions on associated objects.
  • The following DML statements support synonyms: SELECT, INSERT, UPDATE, DELETE, EXPLAIN, and CALL.
  • The CREATE SYNONYM statement of an associated function or stored procedure cannot be used in a stored procedure. You are advised to use synonyms existing in the pg_synonym system catalog in the stored procedure.
  • You are advised not to create synonyms for temporary tables. To create a synonym, you need to specify the schema name of the target temporary table. Otherwise, the synonym cannot be used normally. In addition, you need to run the DROP SYNONYM command before the current session ends.
  • After an original object is deleted, the synonym associated with the object will not be deleted in cascading mode. If you continue to access the synonym, for accessed tables, a message is displayed indicating that the synonym has expired; for accessed functions, stored procedures, and packages, a message is displayed indicating that the objects do not exist.
  • Users granted the CREATE ANY SYNONYM permission can create synonyms in user schemas.
  • Synonyms cannot be created for encrypted tables that contain encrypted columns and views, functions, and stored procedures based on encrypted tables.
  • If the schema of a synonym is the schema to which the user belongs, the owner of the synonym is also the owner of the schema. In other scenarios, the owner of the synonym is the creator of the synonym by default.
  • If SEARCH_PATH is set and no synonym schema is specified, for stored procedures and functions, the PG_PROC table is preferentially searched by name. If no function with the same name exists, synonyms are searched based on SEARCH_PATH. For other objects, SEARCH_PATH is preferentially searched, if their schemas are the same as that of synonyms, the objects are accessed prior to synonyms.
  • Objects associated with synonyms cannot be accessed using DDL statements, such as CREATE, DROP, and ALTER.
  • Nested synonyms are supported. When you search for a synonym, if the synonym is associated with another synonym, the system continues to search for the associated synonym until the last associated object is found.
  • You cannot use \d, \df, or \sf to access information about associated objects through synonyms.

Syntax

1
2
CREATE [ OR REPLACE ] [PUBLIC] SYNONYM synonym_name 
    FOR object_name;

Parameters

  • OR REPLACE

    (Optional) Redefines the synonym if it already exists.

  • PUBLIC

    (Optional) Creates a PUBLIC synonym.

    • PUBLIC synonyms must be unique in the same database.
    • If the database is upgraded from a version that does not support PUBLIC synonyms to a version that supports PUBLIC synonyms, PUBLIC synonyms cannot be created or deleted before the upgrade is committed.
    • All users can access PUBLIC synonyms. Except the initial users and system administrators, you must have the CREATE PUBLIC SYNONYM and DROP PUBLIC SYNONYM permissions to create and delete PUBLIC synonyms, respectively.
    • For the PUBLIC synonym, the values of synnamespace and synowner in the PG_SYNONYM system catalog are 0, the value of owner in the ADM_SYNONYMS and DB_SYNONYMS system views is PUBLIC, and the value of schema_name is NULL.
    • If no synonym schema is specified, the system searches for objects with the same name to determine whether the objects exist. Then, the system searches for synonyms by SEARCH_PATH. Finally, the system searches for PUBLIC synonyms. If a synonym schema is specified, PUBLIC synonyms are not retrieved.
  • synonym_name

    Specifies the name of the synonym to be created, which can contain the schema name.

    Value range: a string. It must comply with the naming convention.

  • object_name

    Specifies the name of an object that is associated (optionally with schema names).

    Value range: a string. It must comply with the naming convention.

    • object_name can be the name of an object that does not exist.
    • object_name can be the name of a remote object accessed by using a database link. For details about how to use database links, see DATABASE LINK.

Do not create aliases for functions that contain passwords and other sensitive information, such as the encryption functions gs_encrypt and gs_encrypt_bytera, and the decryption functions gs_decrypt and gs_decrypt_bytea or use aliases to call the functions to prevent sensitive information leakage.

Examples

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
-- Create schema ot.
gaussdb=# CREATE SCHEMA ot;

-- Create a table ot.test_tbl1.
gaussdb=# CREATE TABLE ot.test_tbl1(c1 INT, c2 INT);
gaussdb=# INSERT INTO ot.test_tbl1 values(1,1);

-- View the current value of search_path.
gaussdb=# SHOW search_path;
  search_path   
----------------
 "$user",public
(1 row)

-- The current value of search_path does not contain ot, and the current user is not ot. Therefore, an error is reported when you directly view the table name.
gaussdb=# SELECT * FROM test_tbl1;
ERROR:  relation "test_tbl1" does not exist
LINE 1: SELECT * FROM test_tbl1;
                      ^
-- Create a synonym.
gaussdb=# CREATE OR REPLACE SYNONYM test_tbl1 FOR ot.test_tbl1;

-- Use the synonym.
gaussdb=# SELECT * FROM test_tbl1;
 c1 | c2 
----+----
  1 |  1
(1 row)
gaussdb=# INSERT INTO test_tbl1 VALUES (2,2);

-- Query a created synonym.
gaussdb=# SELECT synname,synobjschema,synobjname FROM pg_synonym WHERE synname = 'test_tbl1';
  synname  | synobjschema | synobjname 
-----------+--------------+------------
 test_tbl1 | ot           | test_tbl1
(1 row)

-- Delete.
gaussdb=# DROP SYNONYM test_tbl1;
gaussdb=# DROP TABLE ot.test_tbl1;
gaussdb=# DROP SCHEMA ot CASCADE;

Helpful Links

ALTER SYNONYM and DROP SYNONYM