Updated on 2024-05-07 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 of a synonym should be its owner.
  • If the schema name is specified, create a synonym in the specified schema. Otherwise create a synonym in the current schema.
  • Database objects that can be accessed using synonyms include tables, views, types, packages, functions, and stored procedures.
  • 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 not advised 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 tables, a message is displayed indicating that the synonyms have expired; for 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.

Syntax

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

Parameters

  • OR REPLACE

    (Optional) Redefines the synonym if it already exists.

  • 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 function gs_encrypt and the decryption function gs_decrypt 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
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
-- Create schema ot.
gaussdb=# CREATE SCHEMA ot;

-- Create table ot.t1 and its synonym t1.
gaussdb=# CREATE TABLE ot.t1(id int, name varchar2(10)) DISTRIBUTE BY hash(id);
gaussdb=# CREATE OR REPLACE SYNONYM t1 FOR ot.t1;

-- Use synonym t1.
gaussdb=# SELECT * FROM t1;
gaussdb=# INSERT INTO t1 VALUES (1, 'ada'), (2, 'bob');
gaussdb=# UPDATE t1 SET t1.name = 'cici' WHERE t1.id = 2;

-- Create synonym v1 and its associated view ot.v_t1.
gaussdb=# CREATE SYNONYM v1 FOR ot.v_t1;
gaussdb=# CREATE VIEW ot.v_t1 AS SELECT * FROM ot.t1;

-- Use synonym v1.
gaussdb=# SELECT * FROM v1;

-- Create overloaded function ot.add and its synonym add.
gaussdb=# CREATE OR REPLACE FUNCTION ot.add(a integer, b integer) RETURNS integer AS
$$
SELECT $1 + $2
$$
LANGUAGE sql;

gaussdb=# CREATE OR REPLACE FUNCTION ot.add(a decimal(5,2), b decimal(5,2)) RETURNS decimal(5,2) AS
$$
SELECT $1 + $2
$$
LANGUAGE sql;

gaussdb=# CREATE OR REPLACE SYNONYM add FOR ot.add;

-- Use synonym add.
gaussdb=# SELECT add(1,2);
gaussdb=# SELECT add(1.2,2.3);

-- Create stored procedure ot.register and its synonym register.
gaussdb=# CREATE PROCEDURE ot.register(n_id integer, n_name varchar2(10))
SECURITY INVOKER
AS
BEGIN
    INSERT INTO ot.t1 VALUES(n_id, n_name);
END;
/

gaussdb=# CREATE OR REPLACE SYNONYM register FOR ot.register;

-- Use synonym register to call the stored procedure.
gaussdb=# CALL register(3,'mia');

-- Delete the synonym.
gaussdb=# DROP SYNONYM t1;
gaussdb=# DROP SYNONYM IF EXISTS v1;
gaussdb=# DROP SYNONYM IF EXISTS add;
gaussdb=# DROP SYNONYM register;
gaussdb=# DROP SCHEMA ot CASCADE;

Helpful Links

ALTER SYNONYM and DROP SYNONYM