Updated on 2024-06-03 GMT+08:00

ALTER TYPE

Description

Modifies the definition of a type.

Precautions

Only the owner of a type, a user granted the ALTER permission on a type, or a user granted the ALTER ANY TYPE permission on a sequence can run the ALTER TYPE command. When separation of duties is disabled, system administrators have this permission by default. To modify the owner or schema of a type, you must be a type owner or system administrator and a member of the new owner role.

Syntax

  • Modify a type.
    1
    ALTER TYPE name action [, ... ];
    

    The clauses corresponding to action are as follows:

    • Add a new attribute to a composite type.
      1
      ADD ATTRIBUTE attribute_name data_type [ COLLATE collation ] [ CASCADE | RESTRICT ]
      

    • Delete an attribute from a composite type.
      1
      DROP ATTRIBUTE [ IF EXISTS ] attribute_name [ CASCADE | RESTRICT ]
      

    • Change the type of an attribute in a composite type.
      1
      ALTER ATTRIBUTE attribute_name [ SET DATA ] TYPE data_type [ COLLATE collation ] [ CASCADE | RESTRICT ]
      

  • Change the owner of a type.
    1
    ALTER TYPE name OWNER TO { new_owner | CURRENT_USER | SESSION_USER };
    

  • Change the name of a type.
    ALTER TYPE name RENAME TO new_name;

  • Change the name of an attribute in a composite type.
    1
    ALTER TYPE name RENAME ATTRIBUTE attribute_name TO new_attribute_name [ CASCADE | RESTRICT ];
    

  • Move a type to a new schema.
    1
    ALTER TYPE name SET SCHEMA new_schema;
    

  • Add a new value to an enumerated type.
    1
    ALTER TYPE name ADD VALUE [ IF NOT EXISTS ] new_enum_value [ { BEFORE | AFTER } neighbor_enum_value ];
    

  • Change an enumerated value in the value list.
    1
    ALTER TYPE name RENAME VALUE existing_enum_value TO new_enum_value;
    

Parameters

  • name

    Specifies the name of an existing type that needs to be modified (optionally schema-qualified).

  • new_name

    Specifies the new name of the type.

  • new_owner

    Specifies the new owner of the type.

  • new_schema

    Specifies the new schema of the type.

  • attribute_name

    Specifies the name of the attribute to be added, modified, or deleted.

  • new_attribute_name

    Specifies the new name of the attribute to be renamed.

  • data_type

    Specifies the data type of the attribute to be added, or the new type of the attribute to be modified.

  • new_enum_value

    Specifies a new enumerated value. It is a non-null string with a maximum length of 63 bytes.

  • neighbor_enum_value

    Specifies an existing enumerated value before or after which a new enumerated value will be added.

  • existing_enum_value

    Specifies an enumerated value to be changed. It is a non-null string with a maximum length of 63 bytes.

  • CASCADE

    Determines that the type to be modified, its associated records, and subtables that inherit the type will all be updated.

  • RESTRICT

    (Default) Refuses to update the associated records of the modified type.

    • ADD ATTRIBUTE, DROP ATTRIBUTE, and ALTER ATTRIBUTE can be combined for modifying multiple attributes. For example, it is possible to add several attributes or change the types of several attributes at the same time in one command.
    • To modify a schema of a type, you must have the CREATE permission on the new schema. To alter the owner, you must be a direct or indirect member of the new owner role, and that member must have CREATE permission on the schema of this type (these restrictions enforce that the operation of altering the owner cannot be done by other means other than deleting and rebuilding the type). However, the system administrators can change ownership of any type in any way when separation of duties is disabled.) To add an attribute or modify the type of an attribute, you must also have the USAGE permission of this type.
  • CURRENT_USER

    Specifies the current user.

  • SESSION_USER

    Specifies the current system user.

  • COLLATE collation

    Assigns a collation to the column, which must be a sortable data type. If the collation is not specified, the default collation for the column's data type is used.

Examples

  • Modify a composite type:
    -- Create a composite type.
    gaussdb=# CREATE TYPE typ_stu AS (name varchar(10),age int);
    
    -- Create a table and insert data into the table. The data type of the info column is typ_stu.
    gaussdb=# CREATE TABLE tbl_test (id int PRIMARY KEY,info typ_stu);
    gaussdb=# INSERT INTO tbl_test VALUES (1,('Jim',16));
    
    -- View data in the tbl_test table.
    gaussdb=# SELECT * FROM tbl_test;
     id |   info   
    ----+----------
      1 | (Jim,16)
    (1 row)
    
    -- Add an attribute to a composite type.
    gaussdb=# ALTER TYPE typ_stu ADD ATTRIBUTE year int CASCADE;
    
    -- Check data in the tbl_test table again. The info column contains an extra attribute.
    gaussdb=# SELECT * FROM tbl_test;
     id |   info    
    ----+-----------
      1 | (Jim,16,)
    (1 row)
    
    -- Delete an attribute from a composite type.
    gaussdb=# ALTER TYPE typ_stu DROP ATTRIBUTE year;
  • Change the type owner:
    -- Create a user test.
    gaussdb=# CREATE ROLE test PASSWORD '********';
    
    -- Change the owner of typ_stu to test.
    gaussdb=# ALTER TYPE typ_stu OWNER TO test;
    
    -- Query the owner of typ_stu.
    gaussdb=# SELECT t1.typname, t2.rolname AS owner
    FROM pg_type t1, pg_roles t2 
    WHERE t1.typname = 'typ_stu' AND 
          t1.typowner = t2.oid;
     typname | owner  
    ---------+--------
     typ_stu | test
    (1 row)
  • Change a type or the name of an attribute in a composite type.
    -- Rename one of the attributes age of typ_stu to age1.
    gaussdb=# ALTER TYPE typ_stu RENAME ATTRIBUTE age to age1;
    
    -- Run the following SQL statement to query the data whose age is 16 in the tbl_test table:
    gaussdb=# SELECT id,(info).name,(info).age1 FROM tbl_test WHERE (info).age1 = 16;
     id | name | age1 
    ----+------+------
      1 | Jim  |   16
    (1 row)
  • Move a type to a new schema.
    -- Create a schema sctest.
    gaussdb=# CREATE SCHEMA sctest;
    
    -- Move typ_stu to the sc_test schema.
    gaussdb=# ALTER TYPE typ_stu SET SCHEMA sctest;
    
    -- Query the schema of typ_stu.
    gaussdb=# \dT sctest.*
              List of data types
     Schema |      Name      | Description 
    --------+----------------+-------------
     sctest | sctest.typ_stu | 
    (1 row)
    
    -- Drop the table.
    gaussdb=# DROP TABLE tbl_test;
    gaussdb=# DROP TYPE sctest.typ_stu;
    gaussdb=# DROP ROLE test;
    gaussdb=# DROP SCHEMA sctest;
  • Add a new value to an enumerated type.
    -- Create an enumerated type typ_bugstatus.
    gaussdb=# CREATE TYPE typ_bugstatus AS ENUM ('create', 'modify', 'closed');
    
    -- Create a table tbl_test1.
    gaussdb=# CREATE TABLE tbl_test1 (id serial, bugstat typ_bugstatus);
    
    -- Insert data and ensure that the value of the bugstat column must be of the enumerated type. Otherwise, an error is reported.
    gaussdb=# INSERT INTO tbl_test1 (bugstat) VALUES ('closed');
    gaussdb=# INSERT INTO tbl_test1 (bugstat) VALUES ('deleted');
    ERROR:  invalid input value for enum typ_bugstatus: "deleted"
    LINE 1: INSERT INTO tbl_test1 (bugstat) VALUES ('deleted');
                                                    ^
    CONTEXT:  referenced column: bugstat
    
    -- View data in the tbl_test1 table.
    gaussdb=# SELECT * FROM tbl_test1;
     id | bugstat 
    ----+---------
      1 | closed
    (1 row)
    
    -- Add a tag value to an enumerated type.
    gaussdb=# ALTER TYPE typ_bugstatus ADD VALUE IF NOT EXISTS 'regress' BEFORE 'closed';
    
    -- Query.
    gaussdb=# \dT+ typ_bugstatus
                                         List of data types
     Schema |     Name      | Internal name | Size | Elements | Access privileges | Description 
    --------+---------------+---------------+------+----------+-------------------+-------------
     public | typ_bugstatus | typ_bugstatus | 4    | create  +|                   | 
            |               |               |      | modify  +|                   | 
            |               |               |      | regress +|                   | 
            |               |               |      | closed   |                   | 
    (1 row)
  • Change an enumerated value in the value list.
    -- Change closed in typ_bugstatus to close.
    gaussdb=# ALTER TYPE typ_bugstatus RENAME VALUE 'closed' TO 'close';
    
    -- Check the data in the tbl_test1 table. closed is changed to close.
    gaussdb=# SELECT * FROM tbl_test1;
     id | bugstat 
    ----+---------
      1 | close
    (1 row)
    
    -- Query.
    gaussdb=# \dT+ typ_bugstatus;
                                         List of data types
     Schema |     Name      | Internal name | Size | Elements | Access privileges | Description 
    --------+---------------+---------------+------+----------+-------------------+-------------
     public | typ_bugstatus | typ_bugstatus | 4    | create  +|                   | 
            |               |               |      | modify  +|                   | 
            |               |               |      | regress +|                   | 
            |               |               |      | close    |                   | 
    (1 row)
    
    -- Delete.
    gaussdb=# DROP TABLE tbl_test1;
    gaussdb=# DROP TYPE typ_bugstatus;

Helpful Links

CREATE TYPE and DROP TYPE