COMMENT

Name

COMMENT  --  define or change the comment of an object

Synopsis

    COMMENT ON
    [
      TABLE object_name |
      COLUMN table_name.column_name |
      AGGREGATE agg_name (agg_type) |
      CONSTRAINT constraint_name ON table_name |
      DATABASE object_name |
      DOMAIN object_name |
      FUNCTION func_name (arg1_type, arg2_type, ...) |
      INDEX object_name |
      OPERATOR op (leftoperand_type, rightoperand_type) |
      RULE rule_name ON table_name |
      SCHEMA object_name |
      SEQUENCE object_name |
      TRIGGER trigger_name ON table_name |
      TYPE object_name |
      VIEW object_name
    ] IS 'text'
      

Inputs

object_name, table_name.column_name, agg_name, constraint_name, func_name, op, rule_name, trigger_name

The name of the object to be be commented. Names of tables, aggregates, domains, functions, indexes, operators, sequences, types, and views may be schema-qualified.

text

The comment to add.

Outputs

COMMENT

Message returned if the table is successfully commented.

Description

COMMENT stores a comment about a database object. Comments can be easily retrieved with psql's \dd, \d+, or \l+ commands. Other user interfaces to retrieve comments can be built atop the same built-in functions that psql uses, namely obj_description() and col_description().

To modify a comment, issue a new COMMENT command for the same object. Only one comment string is stored for each object. To remove a comment, write NULL in place of the text string. Comments are automatically dropped when the object is dropped.

Note: There is presently no security mechanism for comments: any user connected to a database can see all the comments for objects in that database (although only superusers can change comments for objects that they don't own). Therefore, don't put security-critical information in comments.

Usage

Attach a comment to the table mytable:

    COMMENT ON TABLE mytable IS 'This is my table.';
       

Remove it again:

    COMMENT ON TABLE mytable IS NULL;
       

Some more examples:

    COMMENT ON AGGREGATE my_aggregate (double precision) IS 'Computes sample variance';
    COMMENT ON COLUMN my_table.my_field IS 'Employee ID number';
    COMMENT ON DATABASE my_database IS 'Development Database';
    COMMENT ON DOMAIN my_domain IS 'Email Address Domain';
    COMMENT ON FUNCTION my_function (timestamp) IS 'Returns Roman Numeral';
    COMMENT ON INDEX my_index IS 'Enforces uniqueness on employee id';
    COMMENT ON OPERATOR ^ (text, text) IS 'Performs intersection of two texts';
    COMMENT ON OPERATOR ^ (NONE, text) IS 'This is a prefix operator on text';
    COMMENT ON RULE my_rule ON my_table IS 'Logs UPDATES of employee records';
    COMMENT ON SCHEMA my_schema IS 'Departmental data';
    COMMENT ON SEQUENCE my_sequence IS 'Used to generate primary keys';
    COMMENT ON TABLE my_schema.my_table IS 'Employee Information';
    COMMENT ON TRIGGER my_trigger ON my_table IS 'Used for R.I.';
    COMMENT ON TYPE complex IS 'Complex Number datatype';
    COMMENT ON VIEW my_view IS 'View of departmental costs';
       

Compatibility

SQL92

There is no COMMENT in SQL92.